From: Tom Lane Date: Tue, 3 Aug 2004 20:32:36 +0000 (+0000) Subject: Add functions pg_start_backup, pg_stop_backup to create backup label X-Git-Tag: REL8_0_0BETA1~82 X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=58c41712d55fadd35477b2ec3a02d12eca2bfbf2;p=postgresql Add functions pg_start_backup, pg_stop_backup to create backup label and history files as per recent discussion. While at it, remove pg_terminate_backend, since we have decided we do not have time during this release cycle to address the reliability concerns it creates. Split the 'Miscellaneous Functions' documentation section into 'System Information Functions' and 'System Administration Functions', which hopefully will draw the eyes of those looking for such things. --- diff --git a/doc/src/sgml/backup.sgml b/doc/src/sgml/backup.sgml index b8b958296c..8b171f3697 100644 --- a/doc/src/sgml/backup.sgml +++ b/doc/src/sgml/backup.sgml @@ -1,5 +1,5 @@ Backup and Restore @@ -14,12 +14,14 @@ $PostgreSQL: pgsql/doc/src/sgml/backup.sgml,v 2.39 2004/04/22 07:02:35 neilc Exp - There are two fundamentally different approaches to backing up + There are three fundamentally different approaches to backing up PostgreSQL data: SQL dump File system level backup + On-line backup + Each has its own strengths and weaknesses. @@ -314,8 +316,8 @@ tar -cf backup.tar /usr/local/pgsql/data The database server must be shut down in order to get a usable backup. Half-way measures such as disallowing all connections will not work - (tar and similar tools do not take an atomic - snapshot of the state of the filesystem at a point in + (mainly because tar and similar tools do not take an + atomic snapshot of the state of the filesystem at a point in time). Information about stopping the server can be found in . Needless to say that you also need to shut down the server before restoring the data. @@ -335,7 +337,8 @@ tar -cf backup.tar /usr/local/pgsql/data information. Of course it is also impossible to restore only a table and the associated pg_clog data because that would render all other tables in the database - cluster useless. + cluster useless. So file system backups only work for complete + restoration of an entire database cluster. @@ -355,7 +358,7 @@ tar -cf backup.tar /usr/local/pgsql/data properly shut down; therefore, when you start the database server on the backed-up data, it will think the server had crashed and replay the WAL log. This is not a problem, just be aware of - it. + it (and be sure to include the WAL files in your dump). @@ -373,6 +376,70 @@ tar -cf backup.tar /usr/local/pgsql/data the contents of indexes for example, just the commands to recreate them.) + + + + On-line backup and point-in-time recovery + + + At all times, PostgreSQL maintains a write ahead + log (WAL) that shows details of every change made to the database's data + files. This log exists primarily for crash-safety purposes: if the system + crashes, the database can be restored to consistency by replaying + the log entries made since the last checkpoint. However, the existence + of the log makes it possible to use a third strategy for backing up + databases: we can combine a filesystem-level backup with backup of the WAL + files. If recovery is needed, we restore the backup and then replay from + the backed-up WAL files to bring the backup up to current time. This + approach is notably more complex to administer than either of the previous + approaches, but it has some significant benefits to offer: + + + + We do not need a perfectly consistent backup as the starting point. + Any internal inconsistency in the backup will be corrected by log + replay (this is not significantly different from what happens during + crash recovery). So we don't need filesystem snapshot capability, + just tar or a similar archiving tool. + + + + + Since we can string together an indefinitely long sequence of WAL files + for replay, continuous backup can be had simply by continuing to archive + the WAL files. This is particularly valuable for large databases, where + making a full backup may take an unreasonable amount of time. + + + + + There is nothing that says we have to replay the WAL entries all the + way to the end. We could stop the replay at any point and have a + consistent snapshot of the database as it was at that time. Thus, + this technique supports point-in-time recovery: it is + possible to restore the database to its state at any time since your base + backup was taken. + + + + + If we continuously feed the series of WAL files to another machine + that's been loaded with the same base backup, we have a hot + standby system: at any point we can bring up the second machine + and it will have a nearly-current copy of the database. + + + + + + + As with the plain filesystem-backup technique, this method can only + support restoration of an entire database cluster, not a subset. + Also, it requires a lot of archival storage: the base backup is bulky, + and a busy system will generate many megabytes of WAL traffic that + have to be archived. Still, it is the preferred backup technique in + many situations where high reliability is needed. + @@ -393,16 +460,16 @@ tar -cf backup.tar /usr/local/pgsql/data change between major releases of PostgreSQL (where the number after the first dot changes). This does not apply to different minor releases under the same major release (where the - number of the second dot changes); these always have compatible + number after the second dot changes); these always have compatible storage formats. For example, releases 7.0.1, 7.1.2, and 7.2 are not compatible, whereas 7.1.1 and 7.1.2 are. When you update - between compatible versions, then you can simply reuse the data - area in disk by the new executables. Otherwise you need to + between compatible versions, you can simply replace the executables + and reuse the data area on disk. Otherwise you need to back up your data and restore it on the new server, using pg_dump. (There are checks in place that prevent you from doing the wrong thing, so no harm can be done by confusing these things.) The precise installation procedure is - not subject of this section; these details are in . @@ -427,7 +494,7 @@ pg_dumpall -p 5432 | psql -d template1 -p 6543 If you cannot or do not want to run two servers in parallel you can - do the back up step before installing the new version, bring down + do the backup step before installing the new version, bring down the server, move the old version out of the way, install the new version, start the new server, restore the data. For example: @@ -447,6 +514,14 @@ psql template1 < backup you of strategic places to perform these steps. + + You will always need a SQL dump (pg_dump dump) for + migrating to a new release. Filesystem-level backups (including + on-line backups) will not work, for the same reason that you can't + just do the update in-place: the file formats won't necessarily be + compatible across major releases. + + When you move the old installation out of the way diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index 8f807fe481..404181482b 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -1,4 +1,4 @@ - + Data Definition @@ -1723,7 +1723,7 @@ SET search_path TO myschema; - See also for other ways to access + See also for other ways to access the schema search path. diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index 998f693c79..f87b7657b5 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -1,5 +1,5 @@ @@ -6629,1356 +6629,1185 @@ SELECT NULLIF(value, '(none)') ... - - Miscellaneous Functions + + Array Functions and Operators - shows several - functions that extract session and system information. + shows the operators + available for array types. - - Session Information Functions - - - Name Return Type Description - - - - - current_database() - name - name of current database - - - - current_schema() - name - name of current schema - - - - current_schemas(boolean) - name[] - names of schemas in search path optionally including implicit schemas - - - - current_user - name - user name of current execution context - - - - inet_client_addr() - inet - address of the remote connection - - - - inet_client_port() - int4 - port of the remote connection - - - - inet_server_addr() - inet - address of the local connection - - - - inet_server_port() - int4 - port of the local connection - - - - session_user - name - session user name - - - - user - name - equivalent to current_user - - - - version() - text - PostgreSQL version information - - - -
- - - user - current - - - - schema - current - - - - search path - current - - - - The session_user is the user that initiated a - database connection; it is fixed for the duration of that - connection. The current_user is the user identifier - that is applicable for permission checking. Normally, it is equal - to the session user, but it changes during the execution of - functions with the attribute SECURITY DEFINER. - In Unix parlance, the session user is the real user and - the current user is the effective user. - - - - - current_user, session_user, and - user have special syntactic status in SQL: - they must be called without trailing parentheses. - - + + <type>array</type> Operators + + + + Operator + Description + Example + Result + + + + + = + equal + ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3] + t + - - current_schema returns the name of the schema that is - at the front of the search path (or a null value if the search path is - empty). This is the schema that will be used for any tables or - other named objects that are created without specifying a target schema. - current_schemas(boolean) returns an array of the names of all - schemas presently in the search path. The Boolean option determines whether or not - implicitly included system schemas such as pg_catalog are included in the search - path returned. - + + <> + not equal + ARRAY[1,2,3] <> ARRAY[1,2,4] + t + - - - The search path may be altered at run time. The command is: - -SET search_path TO schema , schema, ... - - - + + < + less than + ARRAY[1,2,3] < ARRAY[1,2,4] + t + - - inet_client_addr - + + > + greater than + ARRAY[1,4,3] > ARRAY[1,2,4] + t + - - inet_client_port - + + <= + less than or equal + ARRAY[1,2,3] <= ARRAY[1,2,3] + t + - - inet_server_addr - + + >= + greater than or equal + ARRAY[1,4,3] >= ARRAY[1,4,3] + t + - - inet_server_port - + + || + array-to-array concatenation + ARRAY[1,2,3] || ARRAY[4,5,6] + {1,2,3,4,5,6} + - - inet_client_addr returns the IP address of the - current client, and inet_client_port returns the - port number. - inet_server_addr returns the IP address on which - the server accepted the current connection, and - inet_server_port returns the port number. - All these functions return NULL if the connection is via a Unix-domain - socket. - + + || + array-to-array concatenation + ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]] + {{1,2,3},{4,5,6},{7,8,9}} + - - version - + + || + element-to-array concatenation + 3 || ARRAY[4,5,6] + {3,4,5,6} + - - version() returns a string describing the - PostgreSQL server's version. - + + || + array-to-element concatenation + ARRAY[4,5,6] || 7 + {4,5,6,7} + + + +
- shows the functions - available to query and alter run-time configuration parameters. + See for more details about array operator + behavior. - - Configuration Settings Functions - - - Name Return Type Description - + + shows the functions + available for use with array types. See + for more discussion and examples for the use of these functions. + - - - - current_setting(setting_name) - - text - current value of setting - - - - set_config(setting_name, - new_value, - is_local) - - text - set parameter and return new value - - - -
+ + <type>array</type> Functions + + + + Function + Return Type + Description + Example + Result + + + + + + + array_cat + (anyarray, anyarray) + + + anyarray + + concatenate two arrays, returning NULL + for NULL inputs + + array_cat(ARRAY[1,2,3], ARRAY[4,5]) + {1,2,3,4,5} + + + + + array_append + (anyarray, anyelement) + + + anyarray + + append an element to the end of an array, returning + NULL for NULL inputs + + array_append(ARRAY[1,2], 3) + {1,2,3} + + + + + array_prepend + (anyelement, anyarray) + + + anyarray + + append an element to the beginning of an array, returning + NULL for NULL inputs + + array_prepend(1, ARRAY[2,3]) + {1,2,3} + + + + + array_dims + (anyarray) + + + text + + returns a text representation of array dimension lower and upper bounds, + generating an ERROR for NULL inputs + + array_dims(array[[1,2,3], [4,5,6]]) + [1:2][1:3] + + + + + array_lower + (anyarray, integer) + + + integer + + returns lower bound of the requested array dimension, returning + NULL for NULL inputs + + array_lower(array_prepend(0, ARRAY[1,2,3]), 1) + 0 + + + + + array_upper + (anyarray, integer) + + + integer + + returns upper bound of the requested array dimension, returning + NULL for NULL inputs + + array_upper(ARRAY[1,2,3,4], 1) + 4 + + + + + array_to_string + (anyarray, text) + + + text + + concatenates array elements using provided delimiter, returning + NULL for NULL inputs + + array_to_string(array[1, 2, 3], '~^~') + 1~^~2~^~3 + + + + + string_to_array + (text, text) + + + text[] + + splits string into array elements using provided delimiter, returning + NULL for NULL inputs + + string_to_array( 'xx~^~yy~^~zz', '~^~') + {xx,yy,zz} + + + +
+
- - SET - + + Aggregate Functions + + + aggregate function + built-in + + + + Aggregate functions compute a single result + value from a set of input values. shows the built-in aggregate + functions. The special syntax considerations for aggregate + functions are explained in . + Consult for additional introductory + information. + + + + Aggregate Functions + + + + + Function + Argument Type + Return Type + Description + + + + + + + + average + + avg(expression) + + + smallint, integer, + bigint, real, double + precision, numeric, or interval + + + numeric for any integer type argument, + double precision for a floating-point argument, + otherwise the same as the argument data type + + the average (arithmetic mean) of all input values + + + + + + bit_and + + bit_and(expression) + + + smallint, integer, bigint, or + bit + + + same as argument data type + + the bitwise AND of all non-null input values, or null if none + + + + + + bit_or + + bit_or(expression) + + + smallint, integer, bigint, or + bit + + + same as argument data type + + the bitwise OR of all non-null input values, or null if none + + + + + + bool_and + + bool_and(expression) + + + bool + + + bool + + true if all input values are true, otherwise false + + + + + + bool_or + + bool_or(expression) + + + bool + + + bool + + true if at least one input value is true, otherwise false + + + + count(*) + + bigint + number of input values + + + + count(expression) + any + bigint + + number of input values for which the value of expression is not null + + - - SHOW - + + + + every + + every(expression) + + + bool + + + bool + + equivalent to bool_and + - - configuration - of the server - functions - + + max(expression) + any numeric, string, or date/time type + same as argument type + + maximum value of expression across all input + values + + - - The function current_setting yields the - current value of the setting setting_name. - It corresponds to the SQL command - SHOW. An example: - -SELECT current_setting('datestyle'); + + min(expression) + any numeric, string, or date/time type + same as argument type + + minimum value of expression across all input + values + + - current_setting ------------------ - ISO, MDY -(1 row) - - + + + + standard deviation + + stddev(expression) + + + smallint, integer, + bigint, real, double + precision, or numeric + + + double precision for floating-point arguments, + otherwise numeric + + sample standard deviation of the input values + - - set_config sets the parameter - setting_name to - new_value. If - is_local is true, the - new value will only apply to the current transaction. If you want - the new value to apply for the current session, use - false instead. The function corresponds to the - SQL command SET. An example: - -SELECT set_config('log_statement_stats', 'off', false); + + sum(expression) + + smallint, integer, + bigint, real, double + precision, numeric, or + interval + + + bigint for smallint or + integer arguments, numeric for + bigint arguments, double precision + for floating-point arguments, otherwise the same as the + argument data type + + sum of expression across all input values + - set_config ------------- - off -(1 row) - - + + + + variance + + variance(expression) + + + smallint, integer, + bigint, real, double + precision, or numeric + + + double precision for floating-point arguments, + otherwise numeric + + sample variance of the input values (square of the sample standard deviation) + - - privilege - querying - + + +
- lists functions that - allow the user to query object access privileges programmatically. - See for more information about - privileges. + It should be noted that except for count, + these functions return a null value when no rows are selected. In + particular, sum of no rows returns null, not + zero as one might expect. The function coalesce may be + used to substitute zero for null when necessary. - - Access Privilege Inquiry Functions - - - Name Return Type Description - - - - - has_table_privilege(user, - table, - privilege) - - boolean - does user have privilege for table - - - has_table_privilege(table, - privilege) - - boolean - does current user have privilege for table - - - has_database_privilege(user, - database, - privilege) - - boolean - does user have privilege for database - - - has_database_privilege(database, - privilege) - - boolean - does current user have privilege for database - - - has_function_privilege(user, - function, - privilege) - - boolean - does user have privilege for function - - - has_function_privilege(function, - privilege) - - boolean - does current user have privilege for function - - - has_language_privilege(user, - language, - privilege) - - boolean - does user have privilege for language - - - has_language_privilege(language, - privilege) - - boolean - does current user have privilege for language - - - has_schema_privilege(user, - schema, - privilege) - - boolean - does user have privilege for schema - - - has_schema_privilege(schema, - privilege) - - boolean - does current user have privilege for schema - - - has_tablespace_privilege(user, - tablespace, - privilege) - - boolean - does user have privilege for tablespace - - - has_tablespace_privilege(tablespace, - privilege) - - boolean - does current user have privilege for tablespace - - - -
- - - has_table_privilege - - - has_database_privilege - - - has_function_privilege - - - has_language_privilege - - - has_schema_privilege - - - has_tablespace_privilege - + + + ANY + + + SOME + + + Boolean aggregates bool_and and + bool_or correspond to standard SQL aggregates + every and any or + some. + As for any and some, + it seems that there is an ambiguity built into the standard syntax: + +SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...; + + Here ANY can be considered both as leading + to a subquery or as an aggregate if the select expression returns 1 row. + Thus the standard name cannot be given to these aggregates. + + + - has_table_privilege checks whether a user - can access a table in a particular way. The user can be - specified by name or by ID - (pg_user.usesysid), or if the argument is - omitted - current_user is assumed. The table can be specified - by name or by OID. (Thus, there are actually six variants of - has_table_privilege, which can be distinguished by - the number and types of their arguments.) When specifying by name, - the name can be schema-qualified if necessary. - The desired access privilege type - is specified by a text string, which must evaluate to one of the - values SELECT, INSERT, UPDATE, - DELETE, RULE, REFERENCES, or - TRIGGER. (Case of the string is not significant, however.) - An example is: + Users accustomed to working with other SQL database management + systems may be surprised by the performance characteristics of + certain aggregate functions in + PostgreSQL when the aggregate is + applied to the entire table (in other words, no + WHERE clause is specified). In particular, a + query like -SELECT has_table_privilege('myschema.mytable', 'select'); +SELECT min(col) FROM sometable; + will be executed by PostgreSQL using a + sequential scan of the entire table. Other database systems may + optimize queries of this form to use an index on the column, if + one is available. Similarly, the aggregate functions + max() and count() always + require a sequential scan if applied to the entire table in + PostgreSQL. - has_database_privilege checks whether a user - can access a database in a particular way. The possibilities for its - arguments are analogous to has_table_privilege. - The desired access privilege type must evaluate to - CREATE, - TEMPORARY, or - TEMP (which is equivalent to - TEMPORARY). + PostgreSQL cannot easily implement this + optimization because it also allows for user-defined aggregate + queries. Since min(), + max(), and count() are + defined using a generic API for aggregate functions, there is no + provision for special-casing the execution of these functions + under certain circumstances. - has_function_privilege checks whether a user - can access a function in a particular way. The possibilities for its - arguments are analogous to has_table_privilege. - When specifying a function by a text string rather than by OID, - the allowed input is the same as for the regprocedure data type. - The desired access privilege type must evaluate to - EXECUTE. - An example is: + Fortunately, there is a simple workaround for + min() and max(). The + query shown below is equivalent to the query above, except that it + can take advantage of a B-tree index if there is one present on + the column in question. -SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute'); +SELECT col FROM sometable ORDER BY col ASC LIMIT 1; + A similar query (obtained by substituting DESC + for ASC in the query above) can be used in the + place of max()). - has_language_privilege checks whether a user - can access a procedural language in a particular way. The possibilities - for its arguments are analogous to has_table_privilege. - The desired access privilege type must evaluate to - USAGE. + Unfortunately, there is no similarly trivial query that can be + used to improve the performance of count() + when applied to the entire table. + - - has_schema_privilege checks whether a user - can access a schema in a particular way. The possibilities for its - arguments are analogous to has_table_privilege. - The desired access privilege type must evaluate to - CREATE or - USAGE. - +
- - has_tablespace_privilege checks whether a user - can access a tablespace in a particular way. The possibilities for its - arguments are analogous to has_table_privilege. - The desired access privilege type must evaluate to - CREATE. - - - To evaluate whether a user holds a grant option on the privilege, - append WITH GRANT OPTION to the privilege key - word; for example 'UPDATE WITH GRANT OPTION'. - + + Subquery Expressions - - shows functions that - determine whether a certain object is visible in the - current schema search path. A table is said to be visible if its - containing schema is in the search path and no table of the same - name appears earlier in the search path. This is equivalent to the - statement that the table can be referenced by name without explicit - schema qualification. For example, to list the names of all - visible tables: - -SELECT relname FROM pg_class WHERE pg_table_is_visible(oid); - - + + EXISTS + - - Schema Visibility Inquiry Functions - - - Name Return Type Description - + + IN + - - - pg_table_is_visible(table_oid) - - boolean - is table visible in search path - - - pg_type_is_visible(type_oid) - - boolean - is type (or domain) visible in search path - - - pg_function_is_visible(function_oid) - - boolean - is function visible in search path - - - pg_operator_is_visible(operator_oid) - - boolean - is operator visible in search path - - - pg_opclass_is_visible(opclass_oid) - - boolean - is operator class visible in search path - - - pg_conversion_is_visible(conversion_oid) - - boolean - is conversion visible in search path - - - -
+ + NOT IN + - - pg_table_is_visible - - - pg_type_is_visible - - - pg_function_is_visible - - - pg_operator_is_visible - - - pg_opclass_is_visible - - - pg_conversion_is_visible - + + ANY + - - pg_table_is_visible performs the check for - tables (or views, or any other kind of pg_class entry). - pg_type_is_visible, - pg_function_is_visible, - pg_operator_is_visible, - pg_opclass_is_visible, and - pg_conversion_is_visible perform the same sort of - visibility check for types (and domains), functions, operators, operator classes - and conversions, respectively. For functions and operators, an object in - the search path is visible if there is no object of the same name - and argument data type(s) earlier in the path. For - operator classes, both name and associated index access method are - considered. - + + ALL + - - All these functions require object OIDs to identify the object to be - checked. If you want to test an object by name, it is convenient to use - the OID alias types (regclass, regtype, - regprocedure, or regoperator), for example - -SELECT pg_type_is_visible('myschema.widget'::regtype); - - Note that it would not make much sense to test an unqualified name in - this way --- if the name can be recognized at all, it must be visible. - + + SOME + + + + subquery + + + + This section describes the SQL-compliant subquery + expressions available in PostgreSQL. + All of the expression forms documented in this section return + Boolean (true/false) results. + + + + <literal>EXISTS</literal> + + +EXISTS ( subquery ) + + + + The argument of EXISTS is an arbitrary SELECT statement, + or subquery. The + subquery is evaluated to determine whether it returns any rows. + If it returns at least one row, the result of EXISTS is + true; if the subquery returns no rows, the result of EXISTS + is false. + - - pg_get_viewdef - + + The subquery can refer to variables from the surrounding query, + which will act as constants during any one evaluation of the subquery. + - - pg_get_ruledef - + + The subquery will generally only be executed far enough to determine + whether at least one row is returned, not all the way to completion. + It is unwise to write a subquery that has any side effects (such as + calling sequence functions); whether the side effects occur or not + may be difficult to predict. + - - pg_get_indexdef - + + Since the result depends only on whether any rows are returned, + and not on the contents of those rows, the output list of the + subquery is normally uninteresting. A common coding convention is + to write all EXISTS tests in the form + EXISTS(SELECT 1 WHERE ...). There are exceptions to + this rule however, such as subqueries that use INTERSECT. + - - pg_get_triggerdef - + + This simple example is like an inner join on col2, but + it produces at most one output row for each tab1 row, + even if there are multiple matching tab2 rows: + +SELECT col1 FROM tab1 + WHERE EXISTS(SELECT 1 FROM tab2 WHERE col2 = tab1.col2); + + + - - pg_get_constraintdef - + + <literal>IN</literal> - - pg_get_expr - + +expression IN (subquery) + - - pg_get_userbyid - + + The right-hand side is a parenthesized + subquery, which must return exactly one column. The left-hand expression + is evaluated and compared to each row of the subquery result. + The result of IN is true if any equal subquery row is found. + The result is false if no equal row is found (including the special + case where the subquery returns no rows). + - - pg_get_serial_sequence - + + Note that if the left-hand expression yields null, or if there are + no equal right-hand values and at least one right-hand row yields + null, the result of the IN construct will be null, not false. + This is in accordance with SQL's normal rules for Boolean combinations + of null values. + - - pg_tablespace_databases - + + As with EXISTS, it's unwise to assume that the subquery will + be evaluated completely. + + + +row_constructor IN (subquery) + - lists functions that - extract information from the system catalogs. + The left-hand side of this form of IN is a row constructor, + as described in . + The right-hand side is a parenthesized + subquery, which must return exactly as many columns as there are + expressions in the left-hand row. The left-hand expressions are + evaluated and compared row-wise to each row of the subquery result. + The result of IN is true if any equal subquery row is found. + The result is false if no equal row is found (including the special + case where the subquery returns no rows). - - System Catalog Information Functions - - - Name Return Type Description - + + As usual, null values in the rows are combined per + the normal rules of SQL Boolean expressions. Two rows are considered + equal if all their corresponding members are non-null and equal; the rows + are unequal if any corresponding members are non-null and unequal; + otherwise the result of that row comparison is unknown (null). + If all the row results are either unequal or null, with at least one null, + then the result of IN is null. + + - - - pg_get_viewdef(view_name) - text - get CREATE VIEW command for view (deprecated) - - - pg_get_viewdef(view_name, pretty_bool) - text - get CREATE VIEW command for view (deprecated) - - - pg_get_viewdef(view_oid) - text - get CREATE VIEW command for view - - - pg_get_viewdef(view_oid, pretty_bool) - text - get CREATE VIEW command for view - - - pg_get_ruledef(rule_oid) - text - get CREATE RULE command for rule - - - pg_get_ruledef(rule_oid, pretty_bool) - text - get CREATE RULE command for rule - - - pg_get_indexdef(index_oid) - text - get CREATE INDEX command for index - - - pg_get_indexdef(index_oid, column_no, pretty_bool) - text - get CREATE INDEX command for index, - or definition of just one index column when - column_no is not zero - - - pg_get_triggerdef(trigger_oid) - text - get CREATE [ CONSTRAINT ] TRIGGER command for trigger - - - pg_get_constraintdef(constraint_oid) - text - get definition of a constraint - - - pg_get_constraintdef(constraint_oid, pretty_bool) - text - get definition of a constraint - - - pg_get_expr(expr_text, relation_oid) - text - decompile internal form of an expression, assuming that any Vars - in it refer to the relation indicated by the second parameter - - - pg_get_expr(expr_text, relation_oid, pretty_bool) - text - decompile internal form of an expression, assuming that any Vars - in it refer to the relation indicated by the second parameter - - - pg_get_userbyid(userid) - name - get user name with given ID - - - pg_get_serial_sequence(table_name, column_name) - text - get name of the sequence that a serial or bigserial column - uses - - - pg_tablespace_databases(tablespace_oid) - setof oid - get set of database OIDs that have objects in the tablespace - - - -
+ + <literal>NOT IN </literal> + + +expression NOT IN (subquery) + - pg_get_viewdef, - pg_get_ruledef, - pg_get_indexdef, - pg_get_triggerdef, and - pg_get_constraintdef respectively - reconstruct the creating command for a view, rule, index, trigger, or - constraint. (Note that this is a decompiled reconstruction, not - the original text of the command.) - pg_get_expr decompiles the internal form of an - individual expression, such as the default value for a column. It - may be useful when examining the contents of system catalogs. - Most of these functions come in two - variants, one of which can optionally pretty-print the result. - The pretty-printed format is more readable, but the default format is more - likely to be - interpreted the same way by future versions of PostgreSQL; - avoid using pretty-printed output for dump purposes. - Passing false for the pretty-print parameter yields the - same result as the variant that does not have the parameter at all. + The right-hand side is a parenthesized + subquery, which must return exactly one column. The left-hand expression + is evaluated and compared to each row of the subquery result. + The result of NOT IN is true if only unequal subquery rows + are found (including the special case where the subquery returns no rows). + The result is false if any equal row is found. - pg_get_userbyid - extracts a user's name given a user ID number. - pg_get_serial_sequence - fetches the name of the sequence associated with a serial or - bigserial column. The name is suitably formatted - for passing to the sequence functions (see ). - NULL is returned if the column does not have a sequence attached. + Note that if the left-hand expression yields null, or if there are + no equal right-hand values and at least one right-hand row yields + null, the result of the NOT IN construct will be null, not true. + This is in accordance with SQL's normal rules for Boolean combinations + of null values. + + + + As with EXISTS, it's unwise to assume that the subquery will + be evaluated completely. + + + +row_constructor NOT IN (subquery) + + + + The left-hand side of this form of NOT IN is a row constructor, + as described in . + The right-hand side is a parenthesized + subquery, which must return exactly as many columns as there are + expressions in the left-hand row. The left-hand expressions are + evaluated and compared row-wise to each row of the subquery result. + The result of NOT IN is true if only unequal subquery rows + are found (including the special case where the subquery returns no rows). + The result is false if any equal row is found. - pg_tablespace_databases allows usage examination of a - tablespace. It will return a set of OIDs of databases that have objects - stored in the tablespace. If this function returns any row, the - tablespace is not empty and cannot be dropped. To - display the specific objects populating the tablespace, you will need - to connect to the databases identified by - pg_tablespace_databases and query their - pg_class catalogs. + As usual, null values in the rows are combined per + the normal rules of SQL Boolean expressions. Two rows are considered + equal if all their corresponding members are non-null and equal; the rows + are unequal if any corresponding members are non-null and unequal; + otherwise the result of that row comparison is unknown (null). + If all the row results are either unequal or null, with at least one null, + then the result of NOT IN is null. + - - obj_description - + + <literal>ANY</literal>/<literal>SOME</literal> - - col_description - + +expression operator ANY (subquery) +expression operator SOME (subquery) + - - comment - about database objects - + + The right-hand side is a parenthesized + subquery, which must return exactly one column. The left-hand expression + is evaluated and compared to each row of the subquery result using the + given operator, which must yield a Boolean + result. + The result of ANY is true if any true result is obtained. + The result is false if no true result is found (including the special + case where the subquery returns no rows). + - - The functions shown in extract comments - previously stored with the COMMENT command. A - null value is returned if no comment could be found matching the - specified parameters. - + + SOME is a synonym for ANY. + IN is equivalent to = ANY. + - - Comment Information Functions - - - Name Return Type Description - + + Note that if there are no successes and at least one right-hand row yields + null for the operator's result, the result of the ANY construct + will be null, not false. + This is in accordance with SQL's normal rules for Boolean combinations + of null values. + - - - obj_description(object_oid, catalog_name) - text - get comment for a database object - - - obj_description(object_oid) - text - get comment for a database object (deprecated) - - - col_description(table_oid, column_number) - text - get comment for a table column - - - -
+ + As with EXISTS, it's unwise to assume that the subquery will + be evaluated completely. + - - The two-parameter form of obj_description returns the - comment for a database object specified by its OID and the name of the - containing system catalog. For example, - obj_description(123456,'pg_class') - would retrieve the comment for a table with OID 123456. - The one-parameter form of obj_description requires only - the object OID. It is now deprecated since there is no guarantee that - OIDs are unique across different system catalogs; therefore, the wrong - comment could be returned. - + +row_constructor operator ANY (subquery) +row_constructor operator SOME (subquery) + - - col_description returns the comment for a table column, - which is specified by the OID of its table and its column number. - obj_description cannot be used for table columns since - columns do not have OIDs of their own. - + + The left-hand side of this form of ANY is a row constructor, + as described in . + The right-hand side is a parenthesized + subquery, which must return exactly as many columns as there are + expressions in the left-hand row. The left-hand expressions are + evaluated and compared row-wise to each row of the subquery result, + using the given operator. Presently, + only = and <> operators are allowed + in row-wise ANY constructs. + The result of ANY is true if any equal or unequal row is + found, respectively. + The result is false if no such row is found (including the special + case where the subquery returns no rows). + - - pg_cancel_backend - + + As usual, null values in the rows are combined per + the normal rules of SQL Boolean expressions. Two rows are considered + equal if all their corresponding members are non-null and equal; the rows + are unequal if any corresponding members are non-null and unequal; + otherwise the result of that row comparison is unknown (null). + If there is at least one null row result, then the result of ANY + cannot be false; it will be true or null. + +
- - pg_terminate_backend - + + <literal>ALL</literal> - - signal - backend processes - + +expression operator ALL (subquery) + - - The functions shown in send control signals to - other server processes. Use of these functions is restricted - to superusers. - + + The right-hand side is a parenthesized + subquery, which must return exactly one column. The left-hand expression + is evaluated and compared to each row of the subquery result using the + given operator, which must yield a Boolean + result. + The result of ALL is true if all rows yield true + (including the special case where the subquery returns no rows). + The result is false if any false result is found. + - - Backend Signalling Functions - - - Name Return Type Description - - + + NOT IN is equivalent to <> ALL. + - - - - pg_cancel_backend(pid) - - int - Cancel a backend's current query - - - - pg_terminate_backend(pid) - - int - Terminate a backend process - - - -
+ + Note that if there are no failures but at least one right-hand row yields + null for the operator's result, the result of the ALL construct + will be null, not true. + This is in accordance with SQL's normal rules for Boolean combinations + of null values. + - - These functions return 1 if successful, 0 if not successful. - The process ID (pid) of an active backend can be found - from the procpid column in the - pg_stat_activity view, or by listing the postgres - processes on the server. - -
+ + As with EXISTS, it's unwise to assume that the subquery will + be evaluated completely. + - - Array Functions and Operators + +row_constructor operator ALL (subquery) + - shows the operators - available for array types. + The left-hand side of this form of ALL is a row constructor, + as described in . + The right-hand side is a parenthesized + subquery, which must return exactly as many columns as there are + expressions in the left-hand row. The left-hand expressions are + evaluated and compared row-wise to each row of the subquery result, + using the given operator. Presently, + only = and <> operators are allowed + in row-wise ALL queries. + The result of ALL is true if all subquery rows are equal + or unequal, respectively (including the special + case where the subquery returns no rows). + The result is false if any row is found to be unequal or equal, + respectively. - - <type>array</type> Operators - - - - Operator - Description - Example - Result - - - - - = - equal - ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3] - t - + + As usual, null values in the rows are combined per + the normal rules of SQL Boolean expressions. Two rows are considered + equal if all their corresponding members are non-null and equal; the rows + are unequal if any corresponding members are non-null and unequal; + otherwise the result of that row comparison is unknown (null). + If there is at least one null row result, then the result of ALL + cannot be true; it will be false or null. + + + + + Row-wise Comparison + + + comparison + of rows + + + +row_constructor operator (subquery) + - - <> - not equal - ARRAY[1,2,3] <> ARRAY[1,2,4] - t - + + The left-hand side is a row constructor, + as described in . + The right-hand side is a parenthesized subquery, which must return exactly + as many columns as there are expressions in the left-hand row. Furthermore, + the subquery cannot return more than one row. (If it returns zero rows, + the result is taken to be null.) The left-hand side is evaluated and + compared row-wise to the single subquery result row. + Presently, only = and <> operators are allowed + in row-wise comparisons. + The result is true if the two rows are equal or unequal, respectively. + - - < - less than - ARRAY[1,2,3] < ARRAY[1,2,4] - t - + + As usual, null values in the rows are combined per + the normal rules of SQL Boolean expressions. Two rows are considered + equal if all their corresponding members are non-null and equal; the rows + are unequal if any corresponding members are non-null and unequal; + otherwise the result of the row comparison is unknown (null). + + + - - > - greater than - ARRAY[1,4,3] > ARRAY[1,2,4] - t - - - <= - less than or equal - ARRAY[1,2,3] <= ARRAY[1,2,3] - t - + + Row and Array Comparisons - - >= - greater than or equal - ARRAY[1,4,3] >= ARRAY[1,4,3] - t - + + IN + - - || - array-to-array concatenation - ARRAY[1,2,3] || ARRAY[4,5,6] - {1,2,3,4,5,6} - + + NOT IN + - - || - array-to-array concatenation - ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]] - {{1,2,3},{4,5,6},{7,8,9}} - + + ANY + - - || - element-to-array concatenation - 3 || ARRAY[4,5,6] - {3,4,5,6} - + + ALL + - - || - array-to-element concatenation - ARRAY[4,5,6] || 7 - {4,5,6,7} - - - -
+ + SOME + - See for more details about array operator - behavior. + This section describes several specialized constructs for making + multiple comparisons between groups of values. These forms are + syntactically related to the subquery forms of the previous section, + but do not involve subqueries. + The forms involving array subexpressions are + PostgreSQL extensions; the rest are + SQL-compliant. + All of the expression forms documented in this section return + Boolean (true/false) results. - - shows the functions - available for use with array types. See - for more discussion and examples for the use of these functions. - + + <literal>IN</literal> - - <type>array</type> Functions - - - - Function - Return Type - Description - Example - Result - - - - - - - array_cat - (anyarray, anyarray) - - - anyarray - - concatenate two arrays, returning NULL - for NULL inputs - - array_cat(ARRAY[1,2,3], ARRAY[4,5]) - {1,2,3,4,5} - - - - - array_append - (anyarray, anyelement) - - - anyarray - - append an element to the end of an array, returning - NULL for NULL inputs - - array_append(ARRAY[1,2], 3) - {1,2,3} - - - - - array_prepend - (anyelement, anyarray) - - - anyarray - - append an element to the beginning of an array, returning - NULL for NULL inputs - - array_prepend(1, ARRAY[2,3]) - {1,2,3} - - - - - array_dims - (anyarray) - - - text - - returns a text representation of array dimension lower and upper bounds, - generating an ERROR for NULL inputs - - array_dims(array[[1,2,3], [4,5,6]]) - [1:2][1:3] - - - - - array_lower - (anyarray, integer) - - - integer - - returns lower bound of the requested array dimension, returning - NULL for NULL inputs - - array_lower(array_prepend(0, ARRAY[1,2,3]), 1) - 0 - - - - - array_upper - (anyarray, integer) - - - integer - - returns upper bound of the requested array dimension, returning - NULL for NULL inputs - - array_upper(ARRAY[1,2,3,4], 1) - 4 - - - - - array_to_string - (anyarray, text) - - - text - - concatenates array elements using provided delimiter, returning - NULL for NULL inputs - - array_to_string(array[1, 2, 3], '~^~') - 1~^~2~^~3 - - - - - string_to_array - (text, text) - - - text[] - - splits string into array elements using provided delimiter, returning - NULL for NULL inputs - - string_to_array( 'xx~^~yy~^~zz', '~^~') - {xx,yy,zz} - - - -
-
+ +expression IN (value, ...) + + + + The right-hand side is a parenthesized list + of scalar expressions. The result is true if the left-hand expression's + result is equal to any of the right-hand expressions. This is a shorthand + notation for - - Aggregate Functions + +expression = value1 +OR +expression = value2 +OR +... + + - - aggregate function - built-in - + + Note that if the left-hand expression yields null, or if there are + no equal right-hand values and at least one right-hand expression yields + null, the result of the IN construct will be null, not false. + This is in accordance with SQL's normal rules for Boolean combinations + of null values. + + + + + <literal>NOT IN</literal> + + +expression NOT IN (value, ...) + - Aggregate functions compute a single result - value from a set of input values. shows the built-in aggregate - functions. The special syntax considerations for aggregate - functions are explained in . - Consult for additional introductory - information. + The right-hand side is a parenthesized list + of scalar expressions. The result is true if the left-hand expression's + result is unequal to all of the right-hand expressions. This is a shorthand + notation for + + +expression <> value1 +AND +expression <> value2 +AND +... + - - Aggregate Functions + + Note that if the left-hand expression yields null, or if there are + no equal right-hand values and at least one right-hand expression yields + null, the result of the NOT IN construct will be null, not true + as one might naively expect. + This is in accordance with SQL's normal rules for Boolean combinations + of null values. + - - - - Function - Argument Type - Return Type - Description - - + + + x NOT IN y is equivalent to NOT (x IN y) in all + cases. However, null values are much more likely to trip up the novice when + working with NOT IN than when working with IN. + It's best to express your condition positively if possible. + + + - - - - - average - - avg(expression) - - - smallint, integer, - bigint, real, double - precision, numeric, or interval - - - numeric for any integer type argument, - double precision for a floating-point argument, - otherwise the same as the argument data type - - the average (arithmetic mean) of all input values - + + <literal>ANY</literal>/<literal>SOME</literal> (array) - - - - bit_and - - bit_and(expression) - - - smallint, integer, bigint, or - bit - - - same as argument data type - - the bitwise AND of all non-null input values, or null if none - + +expression operator ANY (array expression) +expression operator SOME (array expression) + - - - - bit_or - - bit_or(expression) - - - smallint, integer, bigint, or - bit - - - same as argument data type - - the bitwise OR of all non-null input values, or null if none - + + The right-hand side is a parenthesized expression, which must yield an + array value. + The left-hand expression + is evaluated and compared to each element of the array using the + given operator, which must yield a Boolean + result. + The result of ANY is true if any true result is obtained. + The result is false if no true result is found (including the special + case where the array has zero elements). + - - - - bool_and - - bool_and(expression) - - - bool - - - bool - - true if all input values are true, otherwise false - + + SOME is a synonym for ANY. + + - - - - bool_or - - bool_or(expression) - - - bool - - - bool - - true if at least one input value is true, otherwise false - + + <literal>ALL</literal> (array) - - count(*) - - bigint - number of input values - + +expression operator ALL (array expression) + - - count(expression) - any - bigint - - number of input values for which the value of expression is not null - - + + The right-hand side is a parenthesized expression, which must yield an + array value. + The left-hand expression + is evaluated and compared to each element of the array using the + given operator, which must yield a Boolean + result. + The result of ALL is true if all comparisons yield true + (including the special case where the array has zero elements). + The result is false if any false result is found. + + + + + Row-wise Comparison + + +row_constructor operator row_constructor + + + + Each side is a row constructor, + as described in . + The two row values must have the same number of fields. + Each side is evaluated and they are compared row-wise. + Presently, only = and <> operators are allowed + in row-wise comparisons. + The result is true if the two rows are equal or unequal, respectively. + + + + As usual, null values in the rows are combined per + the normal rules of SQL Boolean expressions. Two rows are considered + equal if all their corresponding members are non-null and equal; the rows + are unequal if any corresponding members are non-null and unequal; + otherwise the result of the row comparison is unknown (null). + + + +row_constructor IS DISTINCT FROM row_constructor + + + + This construct is similar to a <> row comparison, + but it does not yield null for null inputs. Instead, any null value is + considered unequal to (distinct from) any non-null value, and any two + nulls are considered equal (not distinct). Thus the result will always + be either true or false, never null. + + + +row_constructor IS NULL +row_constructor IS NOT NULL + - - - - every - - every(expression) - - - bool - - - bool - - equivalent to bool_and - + + These constructs test a row value for null or not null. A row value + is considered not null if it has at least one field that is not null. + - - max(expression) - any numeric, string, or date/time type - same as argument type - - maximum value of expression across all input - values - - + + - - min(expression) - any numeric, string, or date/time type - same as argument type - - minimum value of expression across all input - values - - + + Set Returning Functions + + + set returning functions + functions + + + + This section describes functions that possibly return more than one row. + Currently the only functions in this class are series generating functions, + as detailed in . + +
+ Series Generating Functions + + - - - standard deviation - - stddev(expression) - - - smallint, integer, - bigint, real, double - precision, or numeric - - - double precision for floating-point arguments, - otherwise numeric - - sample standard deviation of the input values + Function + Argument Type + Return Type + Description + + - sum(expression) - - smallint, integer, - bigint, real, double - precision, numeric, or - interval - + generate_series(start, stop) + int or bigint + setof int or setof bigint (same as argument type) - bigint for smallint or - integer arguments, numeric for - bigint arguments, double precision - for floating-point arguments, otherwise the same as the - argument data type + Generate a series of values, from start to stop + with a step size of one. - sum of expression across all input values + generate_series(start, stop, step) + int or bigint + setof int or setof bigint (same as argument type) - - variance - - variance(expression) - - - smallint, integer, - bigint, real, double - precision, or numeric - - - double precision for floating-point arguments, - otherwise numeric + Generate a series of values, from start to stop + with a step size of step. - sample variance of the input values (square of the sample standard deviation) @@ -7986,754 +7815,988 @@ SELECT pg_type_is_visible('myschema.widget'::regtype);
- It should be noted that except for count, - these functions return a null value when no rows are selected. In - particular, sum of no rows returns null, not - zero as one might expect. The function coalesce may be - used to substitute zero for null when necessary. - - - - - ANY - - - SOME - - - Boolean aggregates bool_and and - bool_or correspond to standard SQL aggregates - every and any or - some. - As for any and some, - it seems that there is an ambiguity built into the standard syntax: + When step is positive, zero rows are returned if + start is greater than stop. + Conversely, when step is negative, zero rows are + returned if start is less than stop. + Zero rows are also returned for NULL inputs. It is an error + for step to be zero. Some examples follow: -SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...; - - Here ANY can be considered both as leading - to a subquery or as an aggregate if the select expression returns 1 row. - Thus the standard name cannot be given to these aggregates. - - +select * from generate_series(2,4); + generate_series +----------------- + 2 + 3 + 4 +(3 rows) - - - Users accustomed to working with other SQL database management - systems may be surprised by the performance characteristics of - certain aggregate functions in - PostgreSQL when the aggregate is - applied to the entire table (in other words, no - WHERE clause is specified). In particular, a - query like - -SELECT min(col) FROM sometable; - - will be executed by PostgreSQL using a - sequential scan of the entire table. Other database systems may - optimize queries of this form to use an index on the column, if - one is available. Similarly, the aggregate functions - max() and count() always - require a sequential scan if applied to the entire table in - PostgreSQL. - +select * from generate_series(5,1,-2); + generate_series +----------------- + 5 + 3 + 1 +(3 rows) - - PostgreSQL cannot easily implement this - optimization because it also allows for user-defined aggregate - queries. Since min(), - max(), and count() are - defined using a generic API for aggregate functions, there is no - provision for special-casing the execution of these functions - under certain circumstances. - +select * from generate_series(4,3); + generate_series +----------------- +(0 rows) - - Fortunately, there is a simple workaround for - min() and max(). The - query shown below is equivalent to the query above, except that it - can take advantage of a B-tree index if there is one present on - the column in question. - -SELECT col FROM sometable ORDER BY col ASC LIMIT 1; +select current_date + s.a as dates from generate_series(0,14,7) as s(a); + dates +------------ + 2004-02-05 + 2004-02-12 + 2004-02-19 +(3 rows) - A similar query (obtained by substituting DESC - for ASC in the query above) can be used in the - place of max()). - - - - Unfortunately, there is no similarly trivial query that can be - used to improve the performance of count() - when applied to the entire table. - - - +
+ + System Information Functions - - Subquery Expressions - - - EXISTS - - - - IN - - - - NOT IN - + + shows several + functions that extract session and system information. + - - ANY - + + Session Information Functions + + + Name Return Type Description + - - ALL - + + + current_database() + name + name of current database + - - SOME - + + current_schema() + name + name of current schema + - - subquery - + + current_schemas(boolean) + name[] + names of schemas in search path optionally including implicit schemas + - - This section describes the SQL-compliant subquery - expressions available in PostgreSQL. - All of the expression forms documented in this section return - Boolean (true/false) results. - + + current_user + name + user name of current execution context + - - <literal>EXISTS</literal> + + inet_client_addr() + inet + address of the remote connection + - -EXISTS ( subquery ) - + + inet_client_port() + int4 + port of the remote connection + - - The argument of EXISTS is an arbitrary SELECT statement, - or subquery. The - subquery is evaluated to determine whether it returns any rows. - If it returns at least one row, the result of EXISTS is - true; if the subquery returns no rows, the result of EXISTS - is false. - + + inet_server_addr() + inet + address of the local connection + - - The subquery can refer to variables from the surrounding query, - which will act as constants during any one evaluation of the subquery. - + + inet_server_port() + int4 + port of the local connection + - - The subquery will generally only be executed far enough to determine - whether at least one row is returned, not all the way to completion. - It is unwise to write a subquery that has any side effects (such as - calling sequence functions); whether the side effects occur or not - may be difficult to predict. - + + session_user + name + session user name + - - Since the result depends only on whether any rows are returned, - and not on the contents of those rows, the output list of the - subquery is normally uninteresting. A common coding convention is - to write all EXISTS tests in the form - EXISTS(SELECT 1 WHERE ...). There are exceptions to - this rule however, such as subqueries that use INTERSECT. - + + user + name + equivalent to current_user + - - This simple example is like an inner join on col2, but - it produces at most one output row for each tab1 row, - even if there are multiple matching tab2 rows: - -SELECT col1 FROM tab1 - WHERE EXISTS(SELECT 1 FROM tab2 WHERE col2 = tab1.col2); - - - + + version() + text + PostgreSQL version information + + + +
- - <literal>IN</literal> + + user + current + - -expression IN (subquery) - + + schema + current + - - The right-hand side is a parenthesized - subquery, which must return exactly one column. The left-hand expression - is evaluated and compared to each row of the subquery result. - The result of IN is true if any equal subquery row is found. - The result is false if no equal row is found (including the special - case where the subquery returns no rows). - + + search path + current + - - Note that if the left-hand expression yields null, or if there are - no equal right-hand values and at least one right-hand row yields - null, the result of the IN construct will be null, not false. - This is in accordance with SQL's normal rules for Boolean combinations - of null values. - + + The session_user is the user that initiated a + database connection; it is fixed for the duration of that + connection. The current_user is the user identifier + that is applicable for permission checking. Normally, it is equal + to the session user, but it changes during the execution of + functions with the attribute SECURITY DEFINER. + In Unix parlance, the session user is the real user and + the current user is the effective user. + - - As with EXISTS, it's unwise to assume that the subquery will - be evaluated completely. - + + + current_user, session_user, and + user have special syntactic status in SQL: + they must be called without trailing parentheses. + + - -row_constructor IN (subquery) - + + current_schema returns the name of the schema that is + at the front of the search path (or a null value if the search path is + empty). This is the schema that will be used for any tables or + other named objects that are created without specifying a target schema. + current_schemas(boolean) returns an array of the names of all + schemas presently in the search path. The Boolean option determines whether or not + implicitly included system schemas such as pg_catalog are included in the search + path returned. + - - The left-hand side of this form of IN is a row constructor, - as described in . - The right-hand side is a parenthesized - subquery, which must return exactly as many columns as there are - expressions in the left-hand row. The left-hand expressions are - evaluated and compared row-wise to each row of the subquery result. - The result of IN is true if any equal subquery row is found. - The result is false if no equal row is found (including the special - case where the subquery returns no rows). - + + + The search path may be altered at run time. The command is: + +SET search_path TO schema , schema, ... + + + - - As usual, null values in the rows are combined per - the normal rules of SQL Boolean expressions. Two rows are considered - equal if all their corresponding members are non-null and equal; the rows - are unequal if any corresponding members are non-null and unequal; - otherwise the result of that row comparison is unknown (null). - If all the row results are either unequal or null, with at least one null, - then the result of IN is null. - - + + inet_client_addr + - - <literal>NOT IN </literal> + + inet_client_port + - -expression NOT IN (subquery) - + + inet_server_addr + - - The right-hand side is a parenthesized - subquery, which must return exactly one column. The left-hand expression - is evaluated and compared to each row of the subquery result. - The result of NOT IN is true if only unequal subquery rows - are found (including the special case where the subquery returns no rows). - The result is false if any equal row is found. - + + inet_server_port + - - Note that if the left-hand expression yields null, or if there are - no equal right-hand values and at least one right-hand row yields - null, the result of the NOT IN construct will be null, not true. - This is in accordance with SQL's normal rules for Boolean combinations - of null values. - + + inet_client_addr returns the IP address of the + current client, and inet_client_port returns the + port number. + inet_server_addr returns the IP address on which + the server accepted the current connection, and + inet_server_port returns the port number. + All these functions return NULL if the connection is via a Unix-domain + socket. + - - As with EXISTS, it's unwise to assume that the subquery will - be evaluated completely. - + + version + - -row_constructor NOT IN (subquery) - + + version() returns a string describing the + PostgreSQL server's version. + - - The left-hand side of this form of NOT IN is a row constructor, - as described in . - The right-hand side is a parenthesized - subquery, which must return exactly as many columns as there are - expressions in the left-hand row. The left-hand expressions are - evaluated and compared row-wise to each row of the subquery result. - The result of NOT IN is true if only unequal subquery rows - are found (including the special case where the subquery returns no rows). - The result is false if any equal row is found. - + + privilege + querying + - As usual, null values in the rows are combined per - the normal rules of SQL Boolean expressions. Two rows are considered - equal if all their corresponding members are non-null and equal; the rows - are unequal if any corresponding members are non-null and unequal; - otherwise the result of that row comparison is unknown (null). - If all the row results are either unequal or null, with at least one null, - then the result of NOT IN is null. + lists functions that + allow the user to query object access privileges programmatically. + See for more information about + privileges. - - - <literal>ANY</literal>/<literal>SOME</literal> + + Access Privilege Inquiry Functions + + + Name Return Type Description + - -expression operator ANY (subquery) -expression operator SOME (subquery) - + + + has_table_privilege(user, + table, + privilege) + + boolean + does user have privilege for table + + + has_table_privilege(table, + privilege) + + boolean + does current user have privilege for table + + + has_database_privilege(user, + database, + privilege) + + boolean + does user have privilege for database + + + has_database_privilege(database, + privilege) + + boolean + does current user have privilege for database + + + has_function_privilege(user, + function, + privilege) + + boolean + does user have privilege for function + + + has_function_privilege(function, + privilege) + + boolean + does current user have privilege for function + + + has_language_privilege(user, + language, + privilege) + + boolean + does user have privilege for language + + + has_language_privilege(language, + privilege) + + boolean + does current user have privilege for language + + + has_schema_privilege(user, + schema, + privilege) + + boolean + does user have privilege for schema + + + has_schema_privilege(schema, + privilege) + + boolean + does current user have privilege for schema + + + has_tablespace_privilege(user, + tablespace, + privilege) + + boolean + does user have privilege for tablespace + + + has_tablespace_privilege(tablespace, + privilege) + + boolean + does current user have privilege for tablespace + + + +
- - The right-hand side is a parenthesized - subquery, which must return exactly one column. The left-hand expression - is evaluated and compared to each row of the subquery result using the - given operator, which must yield a Boolean - result. - The result of ANY is true if any true result is obtained. - The result is false if no true result is found (including the special - case where the subquery returns no rows). - + + has_table_privilege + + + has_database_privilege + + + has_function_privilege + + + has_language_privilege + + + has_schema_privilege + + + has_tablespace_privilege + - - SOME is a synonym for ANY. - IN is equivalent to = ANY. - + + has_table_privilege checks whether a user + can access a table in a particular way. The user can be + specified by name or by ID + (pg_user.usesysid), or if the argument is + omitted + current_user is assumed. The table can be specified + by name or by OID. (Thus, there are actually six variants of + has_table_privilege, which can be distinguished by + the number and types of their arguments.) When specifying by name, + the name can be schema-qualified if necessary. + The desired access privilege type + is specified by a text string, which must evaluate to one of the + values SELECT, INSERT, UPDATE, + DELETE, RULE, REFERENCES, or + TRIGGER. (Case of the string is not significant, however.) + An example is: + +SELECT has_table_privilege('myschema.mytable', 'select'); + + - - Note that if there are no successes and at least one right-hand row yields - null for the operator's result, the result of the ANY construct - will be null, not false. - This is in accordance with SQL's normal rules for Boolean combinations - of null values. - + + has_database_privilege checks whether a user + can access a database in a particular way. The possibilities for its + arguments are analogous to has_table_privilege. + The desired access privilege type must evaluate to + CREATE, + TEMPORARY, or + TEMP (which is equivalent to + TEMPORARY). + - - As with EXISTS, it's unwise to assume that the subquery will - be evaluated completely. - + + has_function_privilege checks whether a user + can access a function in a particular way. The possibilities for its + arguments are analogous to has_table_privilege. + When specifying a function by a text string rather than by OID, + the allowed input is the same as for the regprocedure data type. + The desired access privilege type must evaluate to + EXECUTE. + An example is: + +SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute'); + + - -row_constructor operator ANY (subquery) -row_constructor operator SOME (subquery) - + + has_language_privilege checks whether a user + can access a procedural language in a particular way. The possibilities + for its arguments are analogous to has_table_privilege. + The desired access privilege type must evaluate to + USAGE. + + + + has_schema_privilege checks whether a user + can access a schema in a particular way. The possibilities for its + arguments are analogous to has_table_privilege. + The desired access privilege type must evaluate to + CREATE or + USAGE. + + + + has_tablespace_privilege checks whether a user + can access a tablespace in a particular way. The possibilities for its + arguments are analogous to has_table_privilege. + The desired access privilege type must evaluate to + CREATE. + - The left-hand side of this form of ANY is a row constructor, - as described in . - The right-hand side is a parenthesized - subquery, which must return exactly as many columns as there are - expressions in the left-hand row. The left-hand expressions are - evaluated and compared row-wise to each row of the subquery result, - using the given operator. Presently, - only = and <> operators are allowed - in row-wise ANY constructs. - The result of ANY is true if any equal or unequal row is - found, respectively. - The result is false if no such row is found (including the special - case where the subquery returns no rows). + To evaluate whether a user holds a grant option on the privilege, + append WITH GRANT OPTION to the privilege key + word; for example 'UPDATE WITH GRANT OPTION'. - As usual, null values in the rows are combined per - the normal rules of SQL Boolean expressions. Two rows are considered - equal if all their corresponding members are non-null and equal; the rows - are unequal if any corresponding members are non-null and unequal; - otherwise the result of that row comparison is unknown (null). - If there is at least one null row result, then the result of ANY - cannot be false; it will be true or null. + shows functions that + determine whether a certain object is visible in the + current schema search path. A table is said to be visible if its + containing schema is in the search path and no table of the same + name appears earlier in the search path. This is equivalent to the + statement that the table can be referenced by name without explicit + schema qualification. For example, to list the names of all + visible tables: + +SELECT relname FROM pg_class WHERE pg_table_is_visible(oid); + -
- - <literal>ALL</literal> + + Schema Visibility Inquiry Functions + + + Name Return Type Description + - -expression operator ALL (subquery) - + + + pg_table_is_visible(table_oid) + + boolean + is table visible in search path + + + pg_type_is_visible(type_oid) + + boolean + is type (or domain) visible in search path + + + pg_function_is_visible(function_oid) + + boolean + is function visible in search path + + + pg_operator_is_visible(operator_oid) + + boolean + is operator visible in search path + + + pg_opclass_is_visible(opclass_oid) + + boolean + is operator class visible in search path + + + pg_conversion_is_visible(conversion_oid) + + boolean + is conversion visible in search path + + + +
- - The right-hand side is a parenthesized - subquery, which must return exactly one column. The left-hand expression - is evaluated and compared to each row of the subquery result using the - given operator, which must yield a Boolean - result. - The result of ALL is true if all rows yield true - (including the special case where the subquery returns no rows). - The result is false if any false result is found. - + + pg_table_is_visible + + + pg_type_is_visible + + + pg_function_is_visible + + + pg_operator_is_visible + + + pg_opclass_is_visible + + + pg_conversion_is_visible + - - NOT IN is equivalent to <> ALL. - + + pg_table_is_visible performs the check for + tables (or views, or any other kind of pg_class entry). + pg_type_is_visible, + pg_function_is_visible, + pg_operator_is_visible, + pg_opclass_is_visible, and + pg_conversion_is_visible perform the same sort of + visibility check for types (and domains), functions, operators, operator classes + and conversions, respectively. For functions and operators, an object in + the search path is visible if there is no object of the same name + and argument data type(s) earlier in the path. For + operator classes, both name and associated index access method are + considered. + - - Note that if there are no failures but at least one right-hand row yields - null for the operator's result, the result of the ALL construct - will be null, not true. - This is in accordance with SQL's normal rules for Boolean combinations - of null values. - + + All these functions require object OIDs to identify the object to be + checked. If you want to test an object by name, it is convenient to use + the OID alias types (regclass, regtype, + regprocedure, or regoperator), for example + +SELECT pg_type_is_visible('myschema.widget'::regtype); + + Note that it would not make much sense to test an unqualified name in + this way --- if the name can be recognized at all, it must be visible. + - - As with EXISTS, it's unwise to assume that the subquery will - be evaluated completely. - + + pg_get_viewdef + - -row_constructor operator ALL (subquery) - + + pg_get_ruledef + - - The left-hand side of this form of ALL is a row constructor, - as described in . - The right-hand side is a parenthesized - subquery, which must return exactly as many columns as there are - expressions in the left-hand row. The left-hand expressions are - evaluated and compared row-wise to each row of the subquery result, - using the given operator. Presently, - only = and <> operators are allowed - in row-wise ALL queries. - The result of ALL is true if all subquery rows are equal - or unequal, respectively (including the special - case where the subquery returns no rows). - The result is false if any row is found to be unequal or equal, - respectively. - + + pg_get_indexdef + - - As usual, null values in the rows are combined per - the normal rules of SQL Boolean expressions. Two rows are considered - equal if all their corresponding members are non-null and equal; the rows - are unequal if any corresponding members are non-null and unequal; - otherwise the result of that row comparison is unknown (null). - If there is at least one null row result, then the result of ALL - cannot be true; it will be false or null. - -
+ + pg_get_triggerdef + - - Row-wise Comparison + + pg_get_constraintdef + - - comparison - of rows + + pg_get_expr - -row_constructor operator (subquery) - + + pg_get_userbyid + + + + pg_get_serial_sequence + + + + pg_tablespace_databases + - The left-hand side is a row constructor, - as described in . - The right-hand side is a parenthesized subquery, which must return exactly - as many columns as there are expressions in the left-hand row. Furthermore, - the subquery cannot return more than one row. (If it returns zero rows, - the result is taken to be null.) The left-hand side is evaluated and - compared row-wise to the single subquery result row. - Presently, only = and <> operators are allowed - in row-wise comparisons. - The result is true if the two rows are equal or unequal, respectively. + lists functions that + extract information from the system catalogs. + + System Catalog Information Functions + + + Name Return Type Description + + + + + pg_get_viewdef(view_name) + text + get CREATE VIEW command for view (deprecated) + + + pg_get_viewdef(view_name, pretty_bool) + text + get CREATE VIEW command for view (deprecated) + + + pg_get_viewdef(view_oid) + text + get CREATE VIEW command for view + + + pg_get_viewdef(view_oid, pretty_bool) + text + get CREATE VIEW command for view + + + pg_get_ruledef(rule_oid) + text + get CREATE RULE command for rule + + + pg_get_ruledef(rule_oid, pretty_bool) + text + get CREATE RULE command for rule + + + pg_get_indexdef(index_oid) + text + get CREATE INDEX command for index + + + pg_get_indexdef(index_oid, column_no, pretty_bool) + text + get CREATE INDEX command for index, + or definition of just one index column when + column_no is not zero + + + pg_get_triggerdef(trigger_oid) + text + get CREATE [ CONSTRAINT ] TRIGGER command for trigger + + + pg_get_constraintdef(constraint_oid) + text + get definition of a constraint + + + pg_get_constraintdef(constraint_oid, pretty_bool) + text + get definition of a constraint + + + pg_get_expr(expr_text, relation_oid) + text + decompile internal form of an expression, assuming that any Vars + in it refer to the relation indicated by the second parameter + + + pg_get_expr(expr_text, relation_oid, pretty_bool) + text + decompile internal form of an expression, assuming that any Vars + in it refer to the relation indicated by the second parameter + + + pg_get_userbyid(userid) + name + get user name with given ID + + + pg_get_serial_sequence(table_name, column_name) + text + get name of the sequence that a serial or bigserial column + uses + + + pg_tablespace_databases(tablespace_oid) + setof oid + get set of database OIDs that have objects in the tablespace + + + +
+ - As usual, null values in the rows are combined per - the normal rules of SQL Boolean expressions. Two rows are considered - equal if all their corresponding members are non-null and equal; the rows - are unequal if any corresponding members are non-null and unequal; - otherwise the result of the row comparison is unknown (null). + pg_get_viewdef, + pg_get_ruledef, + pg_get_indexdef, + pg_get_triggerdef, and + pg_get_constraintdef respectively + reconstruct the creating command for a view, rule, index, trigger, or + constraint. (Note that this is a decompiled reconstruction, not + the original text of the command.) + pg_get_expr decompiles the internal form of an + individual expression, such as the default value for a column. It + may be useful when examining the contents of system catalogs. + Most of these functions come in two + variants, one of which can optionally pretty-print the result. + The pretty-printed format is more readable, but the default format is more + likely to be + interpreted the same way by future versions of PostgreSQL; + avoid using pretty-printed output for dump purposes. + Passing false for the pretty-print parameter yields the + same result as the variant that does not have the parameter at all. -
-
- - - - Row and Array Comparisons - - - IN - - - - NOT IN - - - - ANY - - - - ALL - - - - SOME - - This section describes several specialized constructs for making - multiple comparisons between groups of values. These forms are - syntactically related to the subquery forms of the previous section, - but do not involve subqueries. - The forms involving array subexpressions are - PostgreSQL extensions; the rest are - SQL-compliant. - All of the expression forms documented in this section return - Boolean (true/false) results. + pg_get_userbyid + extracts a user's name given a user ID number. + pg_get_serial_sequence + fetches the name of the sequence associated with a serial or + bigserial column. The name is suitably formatted + for passing to the sequence functions (see ). + NULL is returned if the column does not have a sequence attached. - - <literal>IN</literal> - - -expression IN (value, ...) - - - The right-hand side is a parenthesized list - of scalar expressions. The result is true if the left-hand expression's - result is equal to any of the right-hand expressions. This is a shorthand - notation for - - -expression = value1 -OR -expression = value2 -OR -... - + pg_tablespace_databases allows usage examination of a + tablespace. It will return a set of OIDs of databases that have objects + stored in the tablespace. If this function returns any row, the + tablespace is not empty and cannot be dropped. To + display the specific objects populating the tablespace, you will need + to connect to the databases identified by + pg_tablespace_databases and query their + pg_class catalogs. - - Note that if the left-hand expression yields null, or if there are - no equal right-hand values and at least one right-hand expression yields - null, the result of the IN construct will be null, not false. - This is in accordance with SQL's normal rules for Boolean combinations - of null values. - - + + obj_description + - - <literal>NOT IN</literal> + + col_description + - -expression NOT IN (value, ...) - + + comment + about database objects + - - The right-hand side is a parenthesized list - of scalar expressions. The result is true if the left-hand expression's - result is unequal to all of the right-hand expressions. This is a shorthand - notation for + + The functions shown in extract comments + previously stored with the COMMENT command. A + null value is returned if no comment could be found matching the + specified parameters. + - -expression <> value1 -AND -expression <> value2 -AND -... - - + + Comment Information Functions + + + Name Return Type Description + - - Note that if the left-hand expression yields null, or if there are - no equal right-hand values and at least one right-hand expression yields - null, the result of the NOT IN construct will be null, not true - as one might naively expect. - This is in accordance with SQL's normal rules for Boolean combinations - of null values. - + + + obj_description(object_oid, catalog_name) + text + get comment for a database object + + + obj_description(object_oid) + text + get comment for a database object (deprecated) + + + col_description(table_oid, column_number) + text + get comment for a table column + + + +
- - - x NOT IN y is equivalent to NOT (x IN y) in all - cases. However, null values are much more likely to trip up the novice when - working with NOT IN than when working with IN. - It's best to express your condition positively if possible. - - -
+ + The two-parameter form of obj_description returns the + comment for a database object specified by its OID and the name of the + containing system catalog. For example, + obj_description(123456,'pg_class') + would retrieve the comment for a table with OID 123456. + The one-parameter form of obj_description requires only + the object OID. It is now deprecated since there is no guarantee that + OIDs are unique across different system catalogs; therefore, the wrong + comment could be returned. + - - <literal>ANY</literal>/<literal>SOME</literal> (array) + + col_description returns the comment for a table column, + which is specified by the OID of its table and its column number. + obj_description cannot be used for table columns since + columns do not have OIDs of their own. + +
- -expression operator ANY (array expression) -expression operator SOME (array expression) - + + System Administration Functions - The right-hand side is a parenthesized expression, which must yield an - array value. - The left-hand expression - is evaluated and compared to each element of the array using the - given operator, which must yield a Boolean - result. - The result of ANY is true if any true result is obtained. - The result is false if no true result is found (including the special - case where the array has zero elements). + shows the functions + available to query and alter run-time configuration parameters. - - SOME is a synonym for ANY. - - + + Configuration Settings Functions + + + Name Return Type Description + - - <literal>ALL</literal> (array) + + + + current_setting(setting_name) + + text + current value of setting + + + + set_config(setting_name, + new_value, + is_local) + + text + set parameter and return new value + + + +
- -expression operator ALL (array expression) - + + SET + - - The right-hand side is a parenthesized expression, which must yield an - array value. - The left-hand expression - is evaluated and compared to each element of the array using the - given operator, which must yield a Boolean - result. - The result of ALL is true if all comparisons yield true - (including the special case where the array has zero elements). - The result is false if any false result is found. - - + + SHOW + - - Row-wise Comparison + + configuration + of the server + functions + - -row_constructor operator row_constructor - + + The function current_setting yields the + current value of the setting setting_name. + It corresponds to the SQL command + SHOW. An example: + +SELECT current_setting('datestyle'); - - Each side is a row constructor, - as described in . - The two row values must have the same number of fields. - Each side is evaluated and they are compared row-wise. - Presently, only = and <> operators are allowed - in row-wise comparisons. - The result is true if the two rows are equal or unequal, respectively. - + current_setting +----------------- + ISO, MDY +(1 row) + + - - As usual, null values in the rows are combined per - the normal rules of SQL Boolean expressions. Two rows are considered - equal if all their corresponding members are non-null and equal; the rows - are unequal if any corresponding members are non-null and unequal; - otherwise the result of the row comparison is unknown (null). - + + set_config sets the parameter + setting_name to + new_value. If + is_local is true, the + new value will only apply to the current transaction. If you want + the new value to apply for the current session, use + false instead. The function corresponds to the + SQL command SET. An example: + +SELECT set_config('log_statement_stats', 'off', false); - -row_constructor IS DISTINCT FROM row_constructor - + set_config +------------ + off +(1 row) + + - - This construct is similar to a <> row comparison, - but it does not yield null for null inputs. Instead, any null value is - considered unequal to (distinct from) any non-null value, and any two - nulls are considered equal (not distinct). Thus the result will always - be either true or false, never null. - + + pg_cancel_backend + - -row_constructor IS NULL -row_constructor IS NOT NULL - + + signal + backend processes + - - These constructs test a row value for null or not null. A row value - is considered not null if it has at least one field that is not null. - + + The function shown in sends control signals to + other server processes. Use of this function is restricted + to superusers. + - -
+ + Backend Signalling Functions + + + Name Return Type Description + + - - Set Returning Functions + + + + pg_cancel_backend(pid) + + int + Cancel a backend's current query + + + +
- - set returning functions - functions - + + This function returns 1 if successful, 0 if not successful. + The process ID (pid) of an active backend can be found + from the procpid column in the + pg_stat_activity view, or by listing the postgres + processes on the server with ps. + - - This section describes functions that possibly return more than one row. - Currently the only functions in this class are series generating functions, - as detailed in . - + + pg_start_backup + - - Series Generating Functions - - - - Function - Argument Type - Return Type - Description - - + + pg_stop_backup + - - - generate_series(start, stop) - int or bigint - setof int or setof bigint (same as argument type) - - Generate a series of values, from start to stop - with a step size of one. - - + + backup + - - generate_series(start, stop, step) - int or bigint - setof int or setof bigint (same as argument type) - - Generate a series of values, from start to stop - with a step size of step. - - + + The functions shown in assist in making on-line backups. + Use of these functions is restricted to superusers. + - - -
+ + Backup Control Functions + + + Name Return Type Description + + - - When step is positive, zero rows are returned if - start is greater than stop. - Conversely, when step is negative, zero rows are - returned if start is less than stop. - Zero rows are also returned for NULL inputs. It is an error - for step to be zero. Some examples follow: - -select * from generate_series(2,4); - generate_series ------------------ - 2 - 3 - 4 -(3 rows) + + + + pg_start_backup(label_text) + + text + Set up for performing on-line backup + + + + pg_stop_backup() + + text + Finish performing on-line backup + + + +
-select * from generate_series(5,1,-2); - generate_series ------------------ - 5 - 3 - 1 -(3 rows) + + pg_start_backup accepts a single parameter which is an + arbitrary user-defined label for the backup. (Typically this would be + the name under which the backup dump file will be stored.) The function + writes a backup label file into the database cluster's data directory, + and then returns the backup's starting WAL offset as text. (The user + need not pay any attention to this result value, but it is provided in + case it is of use.) + -select * from generate_series(4,3); - generate_series ------------------ -(0 rows) + + pg_stop_backup removes the label file created by + pg_start_backup, and instead creates a backup history file in + the WAL archive area. The history file includes the label given to + pg_start_backup, the starting and ending WAL offsets for + the backup, and the starting and ending times of the backup. The return + value is the backup's ending WAL offset (which again may be of little + interest). + -select current_date + s.a as dates from generate_series(0,14,7) as s(a); - dates ------------- - 2004-02-05 - 2004-02-12 - 2004-02-19 -(3 rows) - - -
+ + For details about proper usage of these functions, see + . + +
@@ -229,7 +229,7 @@ SELECT setseed(value); The function set_config provides equivalent - functionality. See . + functionality. See . diff --git a/doc/src/sgml/ref/show.sgml b/doc/src/sgml/ref/show.sgml index 85dbfdcedc..cbd78a9946 100644 --- a/doc/src/sgml/ref/show.sgml +++ b/doc/src/sgml/ref/show.sgml @@ -1,5 +1,5 @@ @@ -130,7 +130,7 @@ SHOW ALL The function current_setting produces - equivalent output. See . + equivalent output. See . diff --git a/src/backend/access/transam/xlog.c b/src/backend/access/transam/xlog.c index b0fac74526..5966658003 100644 --- a/src/backend/access/transam/xlog.c +++ b/src/backend/access/transam/xlog.c @@ -7,7 +7,7 @@ * Portions Copyright (c) 1996-2003, PostgreSQL Global Development Group * Portions Copyright (c) 1994, Regents of the University of California * - * $PostgreSQL: pgsql/src/backend/access/transam/xlog.c,v 1.153 2004/08/01 17:45:42 tgl Exp $ + * $PostgreSQL: pgsql/src/backend/access/transam/xlog.c,v 1.154 2004/08/03 20:32:32 tgl Exp $ * *------------------------------------------------------------------------- */ @@ -5048,3 +5048,233 @@ issue_xlog_fsync(void) break; } } + + +/* + * pg_start_backup: set up for taking an on-line backup dump + * + * Essentially what this does is to create a backup label file in $PGDATA, + * where it will be archived as part of the backup dump. The label file + * contains the user-supplied label string (typically this would be used + * to tell where the backup dump will be stored) and the starting time and + * starting WAL offset for the dump. + */ +Datum +pg_start_backup(PG_FUNCTION_ARGS) +{ + text *backupid = PG_GETARG_TEXT_P(0); + text *result; + char *backupidstr; + XLogRecPtr startpoint; + time_t stamp_time; + char strfbuf[128]; + char labelfilename[MAXPGPATH]; + char xlogfilename[MAXFNAMELEN]; + uint32 _logId; + uint32 _logSeg; + struct stat stat_buf; + FILE *fp; + + if (!superuser()) + ereport(ERROR, + (errcode(ERRCODE_INSUFFICIENT_PRIVILEGE), + (errmsg("must be superuser to run a backup")))); + backupidstr = DatumGetCString(DirectFunctionCall1(textout, + PointerGetDatum(backupid))); + /* + * The oldest point in WAL that would be needed to restore starting from + * the most recent checkpoint is precisely the RedoRecPtr. + */ + startpoint = GetRedoRecPtr(); + XLByteToSeg(startpoint, _logId, _logSeg); + XLogFileName(xlogfilename, ThisTimeLineID, _logId, _logSeg); + /* + * We deliberately use strftime/localtime not the src/timezone functions, + * so that backup labels will consistently be recorded in the same + * timezone regardless of TimeZone setting. This matches elog.c's + * practice. + */ + stamp_time = time(NULL); + strftime(strfbuf, sizeof(strfbuf), + "%Y-%m-%d %H:%M:%S %Z", + localtime(&stamp_time)); + /* + * Check for existing backup label --- implies a backup is already running + */ + snprintf(labelfilename, MAXPGPATH, "%s/backup_label", DataDir); + if (stat(labelfilename, &stat_buf) != 0) + { + if (errno != ENOENT) + ereport(ERROR, + (errcode_for_file_access(), + errmsg("could not stat \"%s\": %m", + labelfilename))); + } + else + ereport(ERROR, + (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE), + errmsg("a backup is already in progress"), + errhint("If you're sure there is no backup in progress, remove file \"%s\" and try again.", + labelfilename))); + /* + * Okay, write the file + */ + fp = AllocateFile(labelfilename, "w"); + if (!fp) + ereport(ERROR, + (errcode_for_file_access(), + errmsg("could not create file \"%s\": %m", + labelfilename))); + fprintf(fp, "START WAL LOCATION: %X/%X (file %s)\n", + startpoint.xlogid, startpoint.xrecoff, xlogfilename); + fprintf(fp, "START TIME: %s\n", strfbuf); + fprintf(fp, "LABEL: %s\n", backupidstr); + if (fflush(fp) || ferror(fp) || FreeFile(fp)) + ereport(ERROR, + (errcode_for_file_access(), + errmsg("could not write file \"%s\": %m", + labelfilename))); + /* + * We're done. As a convenience, return the starting WAL offset. + */ + snprintf(xlogfilename, sizeof(xlogfilename), "%X/%X", + startpoint.xlogid, startpoint.xrecoff); + result = DatumGetTextP(DirectFunctionCall1(textin, + CStringGetDatum(xlogfilename))); + PG_RETURN_TEXT_P(result); +} + +/* + * pg_stop_backup: finish taking an on-line backup dump + * + * We remove the backup label file created by pg_start_backup, and instead + * create a backup history file in pg_xlog (whence it will immediately be + * archived). The backup history file contains the same info found in + * the label file, plus the backup-end time and WAL offset. + */ +Datum +pg_stop_backup(PG_FUNCTION_ARGS) +{ + text *result; + XLogCtlInsert *Insert = &XLogCtl->Insert; + XLogRecPtr startpoint; + XLogRecPtr stoppoint; + time_t stamp_time; + char strfbuf[128]; + char labelfilename[MAXPGPATH]; + char histfilename[MAXPGPATH]; + char startxlogfilename[MAXFNAMELEN]; + char stopxlogfilename[MAXFNAMELEN]; + uint32 _logId; + uint32 _logSeg; + FILE *lfp; + FILE *fp; + char ch; + int ich; + + if (!superuser()) + ereport(ERROR, + (errcode(ERRCODE_INSUFFICIENT_PRIVILEGE), + (errmsg("must be superuser to run a backup")))); + /* + * Get the current end-of-WAL position; it will be unsafe to use this + * dump to restore to a point in advance of this time. + */ + LWLockAcquire(WALInsertLock, LW_EXCLUSIVE); + INSERT_RECPTR(stoppoint, Insert, Insert->curridx); + LWLockRelease(WALInsertLock); + + XLByteToSeg(stoppoint, _logId, _logSeg); + XLogFileName(stopxlogfilename, ThisTimeLineID, _logId, _logSeg); + /* + * We deliberately use strftime/localtime not the src/timezone functions, + * so that backup labels will consistently be recorded in the same + * timezone regardless of TimeZone setting. This matches elog.c's + * practice. + */ + stamp_time = time(NULL); + strftime(strfbuf, sizeof(strfbuf), + "%Y-%m-%d %H:%M:%S %Z", + localtime(&stamp_time)); + /* + * Open the existing label file + */ + snprintf(labelfilename, MAXPGPATH, "%s/backup_label", DataDir); + lfp = AllocateFile(labelfilename, "r"); + if (!lfp) + { + if (errno != ENOENT) + ereport(ERROR, + (errcode_for_file_access(), + errmsg("could not read file \"%s\": %m", + labelfilename))); + ereport(ERROR, + (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE), + errmsg("a backup is not in progress"))); + } + /* + * Read and parse the START WAL LOCATION line (this code is pretty + * crude, but we are not expecting any variability in the file format). + */ + if (fscanf(lfp, "START WAL LOCATION: %X/%X (file %24s)%c", + &startpoint.xlogid, &startpoint.xrecoff, startxlogfilename, + &ch) != 4 || ch != '\n') + ereport(ERROR, + (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE), + errmsg("invalid data in file \"%s\"", labelfilename))); + /* + * Write the backup history file + */ + XLByteToSeg(startpoint, _logId, _logSeg); + BackupHistoryFilePath(histfilename, ThisTimeLineID, _logId, _logSeg, + startpoint.xrecoff % XLogSegSize); + fp = AllocateFile(histfilename, "w"); + if (!fp) + ereport(ERROR, + (errcode_for_file_access(), + errmsg("could not create file \"%s\": %m", + histfilename))); + fprintf(fp, "START WAL LOCATION: %X/%X (file %s)\n", + startpoint.xlogid, startpoint.xrecoff, startxlogfilename); + fprintf(fp, "STOP WAL LOCATION: %X/%X (file %s)\n", + stoppoint.xlogid, stoppoint.xrecoff, stopxlogfilename); + /* transfer start time and label lines from label to history file */ + while ((ich = fgetc(lfp)) != EOF) + fputc(ich, fp); + fprintf(fp, "STOP TIME: %s\n", strfbuf); + if (fflush(fp) || ferror(fp) || FreeFile(fp)) + ereport(ERROR, + (errcode_for_file_access(), + errmsg("could not write file \"%s\": %m", + histfilename))); + /* + * Close and remove the backup label file + */ + if (ferror(lfp) || FreeFile(lfp)) + ereport(ERROR, + (errcode_for_file_access(), + errmsg("could not read file \"%s\": %m", + labelfilename))); + if (unlink(labelfilename) != 0) + ereport(ERROR, + (errcode_for_file_access(), + errmsg("could not remove file \"%s\": %m", + labelfilename))); + /* + * Notify archiver that history file may be archived immediately + */ + if (XLogArchivingActive()) + { + BackupHistoryFileName(histfilename, ThisTimeLineID, _logId, _logSeg, + startpoint.xrecoff % XLogSegSize); + XLogArchiveNotify(histfilename); + } + /* + * We're done. As a convenience, return the ending WAL offset. + */ + snprintf(stopxlogfilename, sizeof(stopxlogfilename), "%X/%X", + stoppoint.xlogid, stoppoint.xrecoff); + result = DatumGetTextP(DirectFunctionCall1(textin, + CStringGetDatum(stopxlogfilename))); + PG_RETURN_TEXT_P(result); +} diff --git a/src/backend/postmaster/pgarch.c b/src/backend/postmaster/pgarch.c index a403896333..960ece7583 100644 --- a/src/backend/postmaster/pgarch.c +++ b/src/backend/postmaster/pgarch.c @@ -19,7 +19,7 @@ * * * IDENTIFICATION - * $PostgreSQL: pgsql/src/backend/postmaster/pgarch.c,v 1.3 2004/08/01 17:45:43 tgl Exp $ + * $PostgreSQL: pgsql/src/backend/postmaster/pgarch.c,v 1.4 2004/08/03 20:32:33 tgl Exp $ * *------------------------------------------------------------------------- */ @@ -64,8 +64,8 @@ * ---------- */ #define MIN_XFN_CHARS 16 -#define MAX_XFN_CHARS 24 -#define VALID_XFN_CHARS "0123456789ABCDEF.history" +#define MAX_XFN_CHARS 40 +#define VALID_XFN_CHARS "0123456789ABCDEF.history.backup" #define NUM_ARCHIVE_RETRIES 3 diff --git a/src/backend/utils/adt/misc.c b/src/backend/utils/adt/misc.c index 0cc315c620..8bf989a865 100644 --- a/src/backend/utils/adt/misc.c +++ b/src/backend/utils/adt/misc.c @@ -8,7 +8,7 @@ * * * IDENTIFICATION - * $PostgreSQL: pgsql/src/backend/utils/adt/misc.c,v 1.35 2004/07/02 18:59:22 joe Exp $ + * $PostgreSQL: pgsql/src/backend/utils/adt/misc.c,v 1.36 2004/08/03 20:32:33 tgl Exp $ * *------------------------------------------------------------------------- */ @@ -27,6 +27,8 @@ #include "catalog/pg_type.h" #include "catalog/pg_tablespace.h" +#define atooid(x) ((Oid) strtoul((x), NULL, 10)) + /* * Check if data is Null @@ -67,8 +69,7 @@ current_database(PG_FUNCTION_ARGS) /* - * Functions to terminate a backend or cancel a query running on - * a different backend. + * Functions to send signals to other backends. */ static int pg_signal_backend(int pid, int sig) @@ -76,14 +77,16 @@ static int pg_signal_backend(int pid, int sig) if (!superuser()) ereport(ERROR, (errcode(ERRCODE_INSUFFICIENT_PRIVILEGE), - (errmsg("only superuser can signal other backends")))); + (errmsg("must be superuser to signal other server processes")))); if (!IsBackendPid(pid)) { - /* This is just a warning so a loop-through-resultset will not abort - * if one backend terminated on it's own during the run */ + /* + * This is just a warning so a loop-through-resultset will not abort + * if one backend terminated on it's own during the run + */ ereport(WARNING, - (errmsg("pid %i is not a postgresql backend",pid))); + (errmsg("PID %d is not a PostgreSQL server process", pid))); return 0; } @@ -91,24 +94,32 @@ static int pg_signal_backend(int pid, int sig) { /* Again, just a warning to allow loops */ ereport(WARNING, - (errmsg("failed to send signal to backend %i: %m",pid))); + (errmsg("could not send signal to process %d: %m",pid))); return 0; } return 1; } Datum -pg_terminate_backend(PG_FUNCTION_ARGS) +pg_cancel_backend(PG_FUNCTION_ARGS) { - PG_RETURN_INT32(pg_signal_backend(PG_GETARG_INT32(0),SIGTERM)); + PG_RETURN_INT32(pg_signal_backend(PG_GETARG_INT32(0),SIGINT)); } +#ifdef NOT_USED + +/* Disabled in 8.0 due to reliability concerns; FIXME someday */ + Datum -pg_cancel_backend(PG_FUNCTION_ARGS) +pg_terminate_backend(PG_FUNCTION_ARGS) { - PG_RETURN_INT32(pg_signal_backend(PG_GETARG_INT32(0),SIGINT)); + PG_RETURN_INT32(pg_signal_backend(PG_GETARG_INT32(0),SIGTERM)); } +#endif + + +/* Function to find out which databases make use of a tablespace */ typedef struct { @@ -140,9 +151,8 @@ Datum pg_tablespace_databases(PG_FUNCTION_ARGS) if (tablespaceOid == GLOBALTABLESPACE_OID) { fctx->dirdesc = NULL; - ereport(NOTICE, - (errcode(ERRCODE_WARNING), - errmsg("global tablespace never has databases."))); + ereport(WARNING, + (errmsg("global tablespace never has databases"))); } else { @@ -154,10 +164,17 @@ Datum pg_tablespace_databases(PG_FUNCTION_ARGS) fctx->dirdesc = AllocateDir(fctx->location); - if (!fctx->dirdesc) /* not a tablespace */ - ereport(NOTICE, - (errcode(ERRCODE_WARNING), - errmsg("%d is no tablespace oid.", tablespaceOid))); + if (!fctx->dirdesc) + { + /* the only expected error is ENOENT */ + if (errno != ENOENT) + ereport(ERROR, + (errcode_for_file_access(), + errmsg("could not open directory \"%s\": %m", + fctx->location))); + ereport(WARNING, + (errmsg("%u is not a tablespace oid", tablespaceOid))); + } } funcctx->user_fctx = fctx; MemoryContextSwitchTo(oldcontext); @@ -174,27 +191,30 @@ Datum pg_tablespace_databases(PG_FUNCTION_ARGS) char *subdir; DIR *dirdesc; - Oid datOid = atol(de->d_name); + Oid datOid = atooid(de->d_name); + /* this test skips . and .., but is awfully weak */ if (!datOid) continue; + /* if database subdir is empty, don't report tablespace as used */ + /* size = path length + dir sep char + file name + terminator */ subdir = palloc(strlen(fctx->location) + 1 + strlen(de->d_name) + 1); sprintf(subdir, "%s/%s", fctx->location, de->d_name); dirdesc = AllocateDir(subdir); - if (dirdesc) - { - while ((de = readdir(dirdesc)) != 0) - { - if (strcmp(de->d_name, ".") && strcmp(de->d_name, "..")) - break; - } - pfree(subdir); - FreeDir(dirdesc); + pfree(subdir); + if (!dirdesc) + continue; /* XXX more sloppiness */ - if (!de) /* database subdir is empty; don't report tablespace as used */ - continue; + while ((de = readdir(dirdesc)) != 0) + { + if (strcmp(de->d_name, ".") != 0 && strcmp(de->d_name, "..") != 0) + break; } + FreeDir(dirdesc); + + if (!de) + continue; /* indeed, nothing in it */ SRF_RETURN_NEXT(funcctx, ObjectIdGetDatum(datOid)); } diff --git a/src/include/access/xlog_internal.h b/src/include/access/xlog_internal.h index 09877bf64b..89c37b7d66 100644 --- a/src/include/access/xlog_internal.h +++ b/src/include/access/xlog_internal.h @@ -11,12 +11,13 @@ * Portions Copyright (c) 1996-2003, PostgreSQL Global Development Group * Portions Copyright (c) 1994, Regents of the University of California * - * $PostgreSQL: pgsql/src/include/access/xlog_internal.h,v 1.1 2004/07/21 22:31:25 tgl Exp $ + * $PostgreSQL: pgsql/src/include/access/xlog_internal.h,v 1.2 2004/08/03 20:32:34 tgl Exp $ */ #ifndef XLOG_INTERNAL_H #define XLOG_INTERNAL_H #include "access/xlog.h" +#include "fmgr.h" #include "storage/block.h" #include "storage/relfilenode.h" @@ -177,7 +178,7 @@ typedef XLogLongPageHeaderData *XLogLongPageHeader; * These macros encapsulate knowledge about the exact layout of XLog file * names, timeline history file names, and archive-status file names. */ -#define MAXFNAMELEN 32 +#define MAXFNAMELEN 64 #define XLogFileName(fname, tli, log, seg) \ snprintf(fname, MAXFNAMELEN, "%08X%08X%08X", tli, log, seg) @@ -194,6 +195,12 @@ typedef XLogLongPageHeaderData *XLogLongPageHeader; #define StatusFilePath(path, xlog, suffix) \ snprintf(path, MAXPGPATH, "%s/archive_status/%s%s", XLogDir, xlog, suffix) +#define BackupHistoryFileName(fname, tli, log, seg, offset) \ + snprintf(fname, MAXFNAMELEN, "%08X%08X%08X.%08X.backup", tli, log, seg, offset) + +#define BackupHistoryFilePath(path, tli, log, seg, offset) \ + snprintf(path, MAXPGPATH, "%s/%08X%08X%08X.%08X.backup", XLogDir, tli, log, seg, offset) + extern char XLogDir[MAXPGPATH]; /* @@ -221,4 +228,10 @@ typedef struct RmgrData extern const RmgrData RmgrTable[]; +/* + * These aren't in xlog.h because I'd rather not include fmgr.h there. + */ +extern Datum pg_start_backup(PG_FUNCTION_ARGS); +extern Datum pg_stop_backup(PG_FUNCTION_ARGS); + #endif /* XLOG_INTERNAL_H */ diff --git a/src/include/catalog/catversion.h b/src/include/catalog/catversion.h index d7d180eaf5..0d5ac8f13c 100644 --- a/src/include/catalog/catversion.h +++ b/src/include/catalog/catversion.h @@ -37,7 +37,7 @@ * Portions Copyright (c) 1996-2003, PostgreSQL Global Development Group * Portions Copyright (c) 1994, Regents of the University of California * - * $PostgreSQL: pgsql/src/include/catalog/catversion.h,v 1.247 2004/07/21 20:43:53 momjian Exp $ + * $PostgreSQL: pgsql/src/include/catalog/catversion.h,v 1.248 2004/08/03 20:32:35 tgl Exp $ * *------------------------------------------------------------------------- */ @@ -53,6 +53,6 @@ */ /* yyyymmddN */ -#define CATALOG_VERSION_NO 200407211 +#define CATALOG_VERSION_NO 200408031 #endif diff --git a/src/include/catalog/pg_proc.h b/src/include/catalog/pg_proc.h index 646fa73dd1..21bd60fb94 100644 --- a/src/include/catalog/pg_proc.h +++ b/src/include/catalog/pg_proc.h @@ -7,7 +7,7 @@ * Portions Copyright (c) 1996-2003, PostgreSQL Global Development Group * Portions Copyright (c) 1994, Regents of the University of California * - * $PostgreSQL: pgsql/src/include/catalog/pg_proc.h,v 1.342 2004/07/12 20:23:53 momjian Exp $ + * $PostgreSQL: pgsql/src/include/catalog/pg_proc.h,v 1.343 2004/08/03 20:32:35 tgl Exp $ * * NOTES * The script catalog/genbki.sh reads this file and generates .bki @@ -2815,11 +2815,6 @@ DESCR("Statistics: Blocks fetched for database"); DATA(insert OID = 1945 ( pg_stat_get_db_blocks_hit PGNSP PGUID 12 f f t f s 1 20 "26" _null_ pg_stat_get_db_blocks_hit - _null_ )); DESCR("Statistics: Blocks found in cache for database"); -DATA(insert OID = 2171 ( pg_terminate_backend PGNSP PGUID 12 f f t f s 1 23 "23" _null_ pg_terminate_backend - _null_ )); -DESCR("Terminate a backend process"); -DATA(insert OID = 2172 ( pg_cancel_backend PGNSP PGUID 12 f f t f s 1 23 "23" _null_ pg_cancel_backend - _null_ )); -DESCR("Cancel running query on a backend process"); - DATA(insert OID = 1946 ( encode PGNSP PGUID 12 f f t f i 2 25 "17 25" _null_ binary_encode - _null_ )); DESCR("Convert bytea value into some ascii-only text string"); DATA(insert OID = 1947 ( decode PGNSP PGUID 12 f f t f i 2 17 "25 25" _null_ binary_decode - _null_ )); @@ -2993,10 +2988,18 @@ DATA(insert OID = 2082 ( pg_operator_is_visible PGNSP PGUID 12 f f t f s 1 16 " DESCR("is operator visible in search path?"); DATA(insert OID = 2083 ( pg_opclass_is_visible PGNSP PGUID 12 f f t f s 1 16 "26" _null_ pg_opclass_is_visible - _null_ )); DESCR("is opclass visible in search path?"); -DATA(insert OID = 2093 ( pg_conversion_is_visible PGNSP PGUID 12 f f t f s 1 16 "26" _null_ pg_conversion_is_visible - _null_ )); +DATA(insert OID = 2093 ( pg_conversion_is_visible PGNSP PGUID 12 f f t f s 1 16 "26" _null_ pg_conversion_is_visible - _null_ )); DESCR("is conversion visible in search path?"); +DATA(insert OID = 2171 ( pg_cancel_backend PGNSP PGUID 12 f f t f v 1 23 "23" _null_ pg_cancel_backend - _null_ )); +DESCR("Cancel a server process' current query"); +DATA(insert OID = 2172 ( pg_start_backup PGNSP PGUID 12 f f t f v 1 25 "25" _null_ pg_start_backup - _null_ )); +DESCR("Prepare for taking an online backup"); +DATA(insert OID = 2173 ( pg_stop_backup PGNSP PGUID 12 f f t f v 0 25 "" _null_ pg_stop_backup - _null_ )); +DESCR("Finish taking an online backup"); + + /* Aggregates (moved here from pg_aggregate for 7.3) */ DATA(insert OID = 2100 ( avg PGNSP PGUID 12 t f f f i 1 1700 "20" _null_ aggregate_dummy - _null_ )); diff --git a/src/include/utils/builtins.h b/src/include/utils/builtins.h index 3e9f58e7f2..09d91d985c 100644 --- a/src/include/utils/builtins.h +++ b/src/include/utils/builtins.h @@ -7,7 +7,7 @@ * Portions Copyright (c) 1996-2003, PostgreSQL Global Development Group * Portions Copyright (c) 1994, Regents of the University of California * - * $PostgreSQL: pgsql/src/include/utils/builtins.h,v 1.246 2004/07/12 20:23:59 momjian Exp $ + * $PostgreSQL: pgsql/src/include/utils/builtins.h,v 1.247 2004/08/03 20:32:36 tgl Exp $ * *------------------------------------------------------------------------- */ @@ -360,7 +360,6 @@ extern Datum float84ge(PG_FUNCTION_ARGS); extern Datum nullvalue(PG_FUNCTION_ARGS); extern Datum nonnullvalue(PG_FUNCTION_ARGS); extern Datum current_database(PG_FUNCTION_ARGS); -extern Datum pg_terminate_backend(PG_FUNCTION_ARGS); extern Datum pg_cancel_backend(PG_FUNCTION_ARGS); extern Datum pg_tablespace_databases(PG_FUNCTION_ARGS);