From d1b4327d02a2c7612797ad0cc3d08a1a23d04686 Mon Sep 17 00:00:00 2001 From: Peter Eisentraut Date: Sun, 4 May 2003 02:23:16 +0000 Subject: [PATCH] Last round of reference page editing. --- doc/src/sgml/ref/declare.sgml | 523 +++---- doc/src/sgml/ref/drop_aggregate.sgml | 249 ++-- doc/src/sgml/ref/drop_cast.sgml | 35 +- doc/src/sgml/ref/drop_conversion.sgml | 45 +- doc/src/sgml/ref/drop_database.sgml | 165 +-- doc/src/sgml/ref/drop_domain.sgml | 186 ++- doc/src/sgml/ref/drop_function.sgml | 192 ++- doc/src/sgml/ref/drop_group.sgml | 151 +- doc/src/sgml/ref/drop_index.sgml | 231 ++-- doc/src/sgml/ref/drop_language.sgml | 241 ++-- doc/src/sgml/ref/drop_opclass.sgml | 224 ++- doc/src/sgml/ref/drop_operator.sgml | 339 ++--- doc/src/sgml/ref/drop_rule.sgml | 245 ++-- doc/src/sgml/ref/drop_schema.sgml | 220 ++- doc/src/sgml/ref/drop_sequence.sgml | 232 ++-- doc/src/sgml/ref/drop_table.sgml | 226 ++- doc/src/sgml/ref/drop_trigger.sgml | 216 ++- doc/src/sgml/ref/drop_type.sgml | 179 ++- doc/src/sgml/ref/drop_user.sgml | 47 +- doc/src/sgml/ref/drop_view.sgml | 227 ++- doc/src/sgml/ref/fetch.sgml | 664 ++++----- doc/src/sgml/ref/move.sgml | 114 +- doc/src/sgml/ref/reset.sgml | 116 +- doc/src/sgml/ref/select.sgml | 1750 +++++++++++------------- doc/src/sgml/ref/select_into.sgml | 174 ++- doc/src/sgml/ref/set.sgml | 447 ++---- doc/src/sgml/ref/set_constraints.sgml | 83 +- doc/src/sgml/ref/set_session_auth.sgml | 42 +- doc/src/sgml/ref/set_transaction.sgml | 52 +- doc/src/sgml/ref/show.sgml | 219 ++- doc/src/sgml/runtime.sgml | 48 +- 31 files changed, 3335 insertions(+), 4547 deletions(-) diff --git a/doc/src/sgml/ref/declare.sgml b/doc/src/sgml/ref/declare.sgml index 49d380e238..0aaf0dde43 100644 --- a/doc/src/sgml/ref/declare.sgml +++ b/doc/src/sgml/ref/declare.sgml @@ -1,5 +1,5 @@ @@ -8,222 +8,23 @@ PostgreSQL documentation DECLARE SQL - Language Statements + - - DECLARE - - - define a cursor - + DECLARE + define a cursor + - - 1999-07-20 - - + DECLARE cursorname [ BINARY ] [ INSENSITIVE ] [ [ NO ] SCROLL ] CURSOR [ { WITH | WITHOUT } HOLD ] FOR query - [ FOR { READ ONLY | UPDATE [ OF column [, ...] ] ] - - - - 1998-04-15 - - - Inputs - - - - - cursorname - - - The name of the cursor to be used in subsequent - FETCH operations. - - - - - - BINARY - - - Causes the cursor to return data in binary rather than in text format. - - - - - - INSENSITIVE - - - SQL92 keyword indicating that data retrieved - from the cursor should be unaffected by updates from other - processes or cursors. By default, all cursors are insensitive. - This keyword currently has no effect and is present for - compatibility with the SQL standard. - - - - - - NO SCROLL - - - Specifies that the cursor cannot be used to retrieve rows in a - nonsequential fashion (e.g., backward). - - - - - - SCROLL - - - Specifies that the cursor may be used to retrieve rows in a - nonsequential fashion (e.g., backward). Depending upon the - complexity of the query's execution plan, specifying - SCROLL may impose a performance penalty - on the query's execution time. - - - - - - WITHOUT HOLD - - - Specifies that the cursor cannot be used outside of the - transaction that created it. If neither WITHOUT - HOLD nor WITH HOLD is specified, - WITHOUT HOLD is the default. - - - - - - WITH HOLD - - - Specifies that the cursor may continue to be used after the - transaction that creates it successfully commits. - - - - - - query - - - A SELECT query which will provide the rows to be - returned by the cursor. - Refer to - for further information about valid arguments. - - - - - - READ ONLY - - - SQL92 keyword indicating that the cursor will be used - in a read only mode. Since this is the only cursor access mode - available in PostgreSQL this keyword has no effect. - - - - - - UPDATE - - - SQL92 keyword indicating that the cursor will be used - to update tables. Since cursor updates are not currently - supported in PostgreSQL this keyword - provokes an informational error message. - - - - - - column - - - Column(s) to be updated. - Since cursor updates are not currently - supported in PostgreSQL the UPDATE clause - provokes an informational error message. - - - - - - - - - The BINARY, INSENSITIVE, - and SCROLL keywords may appear in any order. - - - - - - 1998-04-15 - - - Outputs - - - - - - -DECLARE CURSOR - - - - The message returned if the SELECT is run successfully. - - - - - - -WARNING: Closing pre-existing portal "cursorname" - - - - This message is reported if a cursor with the same name already - exists. The previous definition is discarded. - - - - - - -ERROR: DECLARE CURSOR may only be used in begin/end transaction blocks - - - - This error occurs if the cursor is not declared within a - transaction block, and WITH HOLD is not - specified. - - - - - - + [ FOR { READ ONLY | UPDATE [ OF column [, ...] ] } ] + - - - 1998-09-04 - - - Description - + + Description + DECLARE allows a user to create cursors, which can be used to retrieve @@ -236,51 +37,195 @@ ERROR: DECLARE CURSOR may only be used in begin/end transaction blocks Normal cursors return data in text format, the same as a SELECT would produce. Since data is stored natively in binary format, the system must do a conversion to produce the text - format. In addition, text formats are often larger in size than the - corresponding binary format. Once the information comes back in - text form, the client application may need to convert it to a - binary format to manipulate it. BINARY cursors give you back the - data in the native binary representation. + format. Once the information comes back in text form, the client + application may need to convert it to a binary format to manipulate + it. In addition, data in the text format is often larger in size + than in the binary format. Binary cursors return the data in the + native binary representation. Nevertheless, if you intend to + display the data as text anyway, retrieving it in text form will + save you some effort on the client side. As an example, if a query returns a value of one from an integer column, you would get a string of 1 with a default cursor whereas with a binary cursor you would get - a 4-byte value equal to control-A (^A). + a 4-byte value containing the internal representation of the value. - BINARY cursors should be used carefully. User applications such - as psql are not aware of binary cursors - and expect data to come back in a text format. + Binary cursors should be used carefully. Many applications, + including psql, are not prepared to + handle binary cursors and expect data to come back in the text + format. - String representation is architecture-neutral whereas binary + The string representation is architecture-neutral whereas binary representation can differ between different machine architectures. PostgreSQL does not resolve - byte ordering or representation issues for binary cursors. - Therefore, if your client machine and server machine use different - representations (e.g., big-endian versus little-endian), - you will probably not want your data returned in - binary format. - - - - If you intend to display the data as text, retrieving it in text form - will save you some effort on the client side. - - + byte ordering or representation issues for binary + cursors. Therefore, if your client machine and server + machine use different representations (e.g., + big-endian versus little-endian), you + will probably not want your data returned in binary format. + - - - 1998-09-04 - - - Notes - + + Parameters + + + + cursorname + + + The name of the cursor to be used in subsequent + FETCH operations. + + + + + + BINARY + + + Causes the cursor to return data in binary rather than in text format. + + + + + + INSENSITIVE + + + Indicates that data retrieved from the cursor should be + unaffected by updates to the tables underlying the cursor while + the cursor exists. In PostgreSQL, all cursors are insensitive; + this key word currently has no effect and is present for + compatibility with the SQL standard. + + + + + + SCROLL + NO SCROLL + + + SCROLL specifies that the cursor may be used + to retrieve rows in a nonsequential fashion (e.g., + backward). Depending upon the complexity of the query's + execution plan, specifying SCROLL may impose + a performance penalty on the query's execution time. + NO SCROLL specifies that the cursor cannot be + used to retrieve rows in a nonsequential fashion. + + + + + + WITH HOLD + WITHOUT HOLD + + + WITH HOLD specifies that the cursor may + continue to be used after the transaction that created it + successfully commits. WITHOUT HOLD specifies + that the cursor cannot be used outside of the transaction that + created it. If neither WITHOUT HOLD nor + WITH HOLD is specified, WITHOUT + HOLD is the default. + + + + + + query + + + A SELECT command that will provide the rows to be + returned by the cursor. Refer to for further information about valid + queries. + + + + + + FOR READ ONLY + FOR UPDATE + + + FOR READ ONLY indicates that the cursor will + be used in a read-only mode. FOR UPDATE + indicates that the cursor will be used to update tables. Since + cursor updates are not currently supported in + PostgreSQL, specifying FOR + UPDATE will cause an error message and specifying + FOR READ ONLY has no effect. + + + + + + column + + + Column(s) to be updated by the cursor. Since cursor updates are + not currently supported in + PostgreSQL, the FOR + UPDATE clause provokes an error message. + + + + + + + The key words BINARY, + INSENSITIVE, and SCROLL may + appear in any order. + + + + + Diagnostics + + + + DECLARE CURSOR + + + The message returned if the cursor was successfully defined. + + + + + + WARNING: Closing pre-existing portal "cursorname" + + + This message is reported if a cursor with the same name already + exists. The previous definition is discarded. + + + + + + ERROR: DECLARE CURSOR may only be used in begin/end transaction blocks + + + This error occurs if the cursor is not declared within a + transaction block, and WITH HOLD is not + specified. + + + + + + + + Notes If WITH HOLD is not specified, the cursor @@ -295,87 +240,73 @@ ERROR: DECLARE CURSOR may only be used in begin/end transaction blocks If WITH HOLD is specified and the transaction - that created the cursor successfully commits, the cursor can be - continue to be accessed by subsequent transactions in the same session. - (But if the creating - transaction is aborted, the cursor is removed.) A cursor created - with WITH HOLD is closed when an explicit - CLOSE command is issued on it, or when the client - connection is terminated. In the current implementation, the rows - represented by a held cursor are copied into a temporary file or - memory area so that they remain available for subsequent transactions. + that created the cursor successfully commits, the cursor can + continue to be accessed by subsequent transactions in the same + session. (But if the creating transaction is aborted, the cursor + is removed.) A cursor created with WITH HOLD + is closed when an explicit CLOSE command is + issued on it, or the session ends. In the current implementation, + the rows represented by a held cursor are copied into a temporary + file or memory area so that they remain available for subsequent + transactions. The SCROLL option should be specified when defining a cursor that will be used to fetch backwards. This is required by - SQL92. However, for compatibility with earlier + the SQL standard. However, for compatibility with earlier versions, PostgreSQL will allow backward fetches without SCROLL, if the cursor's query plan is simple enough that no extra overhead is needed to support it. However, application developers are advised not to rely on using backward fetches from a cursor that has not been created - with SCROLL. If NO SCROLL is specified, - then backward fetches are disallowed in any case. + with SCROLL. If NO SCROLL is + specified, then backward fetches are disallowed in any case. - In SQL92 cursors are only available in - embedded SQL (ESQL) applications. - The PostgreSQL backend - does not implement an explicit OPEN cursor - statement; a cursor is considered to be open when it is declared. - However, ecpg, the - embedded SQL preprocessor for PostgreSQL, - supports the SQL92 cursor conventions, including those - involving DECLARE and OPEN statements. + The SQL standard only makes provisions for cursors in embedded + SQL. The PostgreSQL + server does not implement an OPEN statement for + cursors; a cursor is considered to be open when it is declared. + However, ECPG, the embedded SQL + preprocessor for PostgreSQL, supports + the standard SQL cursor conventions, including those involving + DECLARE and OPEN statements. - - - - Usage - + + Examples + To declare a cursor: - - -DECLARE liahona CURSOR - FOR SELECT * FROM films; - + +DECLARE liahona CURSOR FOR SELECT * FROM films; + + See for more + examples of cursor usage. - - - Compatibility - + + Compatibility - - - 1998-04-15 - - - SQL92 - - - SQL92 allows cursors only in embedded - SQL and in modules. PostgreSQL - permits cursors to be used interactively. - + + The SQL standard allows cursors only in embedded + SQL and in modules. PostgreSQL + permits cursors to be used interactively. + - - SQL92 allows embedded or modular cursors to - update database information. All PostgreSQL - cursors are read only. - + + The SQL standard allows cursors to update table data. All + PostgreSQL cursors are read only. + - - The BINARY keyword is a - PostgreSQL extension. - - + + Binary cursors are a PostgreSQL + extension. + diff --git a/doc/src/sgml/ref/drop_aggregate.sgml b/doc/src/sgml/ref/drop_aggregate.sgml index b671fa5c14..539d578653 100644 --- a/doc/src/sgml/ref/drop_aggregate.sgml +++ b/doc/src/sgml/ref/drop_aggregate.sgml @@ -1,5 +1,5 @@ @@ -8,167 +8,126 @@ PostgreSQL documentation DROP AGGREGATE SQL - Language Statements + - - DROP AGGREGATE - - - remove a user-defined aggregate function - + DROP AGGREGATE + remove a user-defined aggregate function + - - 1999-07-20 - - + DROP AGGREGATE name ( type ) [ CASCADE | RESTRICT ] - - - - - 1998-04-15 - - - Inputs - - - - - name - - - The name (optionally schema-qualified) of an existing aggregate function. - - - - - type - - - The input data type of the aggregate function, - or * if the function accepts any input type. - - - - - CASCADE - - - Automatically drop objects that depend on the aggregate. - - - - - RESTRICT - - - Refuse to drop the aggregate if there are any dependent objects. - This is the default. - - - - - - - - - - 1998-04-15 - - - Outputs - - - - - -DROP AGGREGATE - - - - Message returned if the command is successful. - - - - - -ERROR: RemoveAggregate: aggregate 'name' for type type does not exist - - - - This message occurs if the aggregate function specified does not - exist in the database. - - - - - - + - - - 1998-04-15 - - - Description - + + Description + DROP AGGREGATE will delete an existing - aggregate definition. To execute this command the current - user must be the owner of the aggregate. + aggregate function. To execute this command the current + user must be the owner of the aggregate function. - - - - 1998-04-15 - - - Notes - - - - Use - - to create aggregate functions. - - - - - Usage - + + Parameters + + + + name + + + The name (optionally schema-qualified) of an existing aggregate function. + + + + + + type + + + The argument data type of the aggregate function, or + * if the function accepts any data type. + + + + + + CASCADE + + + Automatically drop objects that depend on the aggregate function. + + + + + + RESTRICT + + + Refuse to drop the aggregate function if any objects depend on + it. This is the default. + + + + + + + + Diagnostics + + + + DROP AGGREGATE + + + Message returned if the command was successful. + + + + + + ERROR: RemoveAggregate: aggregate 'name' for type type does not exist + + + This message is returned if the specified aggregate function + does not exist. + + + + + + + + Examples + - To remove the myavg aggregate for type - int4: + To remove the aggregate function myavg for type + integer: + +DROP AGGREGATE myavg(integer); + - -DROP AGGREGATE myavg(int4); - - - - Compatibility - + + Compatibility - - - 1998-04-15 - - - SQL92 - - - - There is no DROP AGGREGATE statement - in SQL92; the statement is a - PostgreSQL - language extension. - - + + There is no DROP AGGREGATE statement in the SQL + standard. + + + + See Also + + + + + + + @@ -13,8 +13,7 @@ -DROP CAST (sourcetype AS targettype) - [ CASCADE | RESTRICT ] +DROP CAST (sourcetype AS targettype) [ CASCADE | RESTRICT ] @@ -30,10 +29,12 @@ DROP CAST (sourcetype AS targettype + + + + Parameters - Parameters - sourcetype @@ -66,45 +67,33 @@ DROP CAST (sourcetype AS targettype - - - Notes - - - Use CREATE CAST to create user-defined casts. - - - - Examples To drop the cast from type text to type int: -DROP CAST (text AS int4); +DROP CAST (text AS int); - Compatibility - The DROP CAST command conforms to SQL99. + The DROP CAST command conforms to the SQL standard. - - + See Also - - - + + + diff --git a/doc/src/sgml/ref/drop_conversion.sgml b/doc/src/sgml/ref/drop_conversion.sgml index 535f1aa159..6e785a84a8 100644 --- a/doc/src/sgml/ref/drop_conversion.sgml +++ b/doc/src/sgml/ref/drop_conversion.sgml @@ -1,4 +1,4 @@ - + @@ -13,8 +13,7 @@ -DROP CONVERSION conversion_name - [ CASCADE | RESTRICT ] +DROP CONVERSION conversion_name [ CASCADE | RESTRICT ] @@ -23,15 +22,14 @@ DROP CONVERSION conversion_name DROP CONVERSION removes a previously defined conversion. - - - To be able to drop a conversion, you must own the conversion. + + + + Parameters - Parameters - conversion_name @@ -55,23 +53,8 @@ DROP CONVERSION conversion_name - - - Notes - - - Use CREATE CONVERSION to create user-defined conversions. - - - - The privileges required to drop a conversion may be changed in a future - release. - - - - Examples @@ -83,25 +66,21 @@ DROP CONVERSION myname; - Compatibility - DROP CONVERSION - is a PostgreSQL extension. - There is no DROP CONVERSION - statement in SQL99. + There is no DROP CONVERSION statement in the SQL + standard. - - + See Also - - - + + + diff --git a/doc/src/sgml/ref/drop_database.sgml b/doc/src/sgml/ref/drop_database.sgml index 4f5095892f..fb77f53c67 100644 --- a/doc/src/sgml/ref/drop_database.sgml +++ b/doc/src/sgml/ref/drop_database.sgml @@ -1,5 +1,5 @@ @@ -8,59 +8,56 @@ PostgreSQL documentation DROP DATABASE SQL - Language Statements + - - DROP DATABASE - - - remove a database - + DROP DATABASE + remove a database + - - 1999-12-11 - - + DROP DATABASE name - + + + + + Description - - - 1999-12-11 - - - Inputs - - - - - name - - - The name of an existing database to remove. - - - - - - + + DROP DATABASE drops a database. It removes the + catalog entries for the database and deletes the directory + containing the data. It can only be executed by the database owner. + - - - 1999-12-11 - - - Outputs - - + + DROP DATABASE cannot be undone. Use it with care! + + + + + Parameters + + + + name + + + The name of the database to remove. + + + + + + + + Diagnostics - DROP DATABASE - This message is returned if the command is successful. + This message is returned if the command was successful. @@ -84,72 +81,34 @@ DROP DATABASE name - - - - - - - - 1999-12-11 - - - Description - - - DROP DATABASE removes the catalog entries for an existing - database and deletes the directory containing the data. - It can only be executed by the database owner (usually the user that created - it). - - - - DROP DATABASE cannot be undone. Use it with care! - - - - - 1999-12-11 - - - Notes - - - - This command cannot be executed while connected to the target - database. Thus, it might be more convenient to use the shell - script , - which is a wrapper around this command, instead. - - - - Refer to - - for information on how to create a database. - - - - - Compatibility - + + Notes - - - 1998-04-15 - - - SQL92 - + + This command cannot be executed while connected to the target + database. Thus, it might be more convenient to use the program + instead, + which is a wrapper around this command. + + - - DROP DATABASE statement is a - PostgreSQL language extension; - there is no such command in SQL92. - - + + Compatibility + + + The is no DROP DATABASE statement in the SQL standard. + + + + + See Also + + + + diff --git a/doc/src/sgml/ref/drop_domain.sgml b/doc/src/sgml/ref/drop_domain.sgml index 5196ae4b89..99c8ec7d44 100644 --- a/doc/src/sgml/ref/drop_domain.sgml +++ b/doc/src/sgml/ref/drop_domain.sgml @@ -1,126 +1,98 @@ - - DROP DOMAIN - + DROP DOMAIN SQL - Language Statements + - - DROP DOMAIN - - - remove a user-defined domain - + DROP DOMAIN + remove a domain + - - 1999-07-20 - - + DROP DOMAIN domainname [, ...] [ CASCADE | RESTRICT ] - - - - - 2002-02-24 - - - Inputs - - - - - domainname - - - The name (optionally schema-qualified) of an existing domain. - - - - - - CASCADE - - - Automatically drop objects that depend on the domain - (such as table columns). - - - - - - RESTRICT - - - Refuse to drop the domain if there are any dependent objects. - This is the default. - - - - - - - - - - 2002-02-24 - - - Outputs - - - - - -DROP DOMAIN - - - - The message returned if the command is successful. - - - - - -ERROR: RemoveDomain: type 'domainname' does not exist - - - - This message occurs if the specified domain (or type) is not found. - - - - - - + - - - 2002-02-24 - - - Description - + + Description + - DROP DOMAIN will remove a user domain from the - system catalogs. - - - Only the owner of a domain can remove it. + DROP DOMAIN will remove a domain. Only the + owner of a domain can remove it. + + Parameters + + + + domainname + + + The name (optionally schema-qualified) of an existing domain. + + + + + + CASCADE + + + Automatically drop objects that depend on the domain (such as + table columns). + + + + + + RESTRICT + + + Refuse to drop the domain if any objects depend on it. This is + the default. + + + + + + + + Diagnostics + + + + DROP DOMAIN + + + Message returned if the command was successful. + + + + + + ERROR: RemoveDomain: type 'domainname' does not exist + + + This message occurs if the specified domain does not exist. + + + + + + Examples + - To remove the box domain: + To remove the domain box: DROP DOMAIN box; @@ -131,13 +103,9 @@ DROP DOMAIN box; Compatibility - - - SQL92 - - - - + + This command conforms to the SQL standard. + diff --git a/doc/src/sgml/ref/drop_function.sgml b/doc/src/sgml/ref/drop_function.sgml index 5f87249989..10504630ff 100644 --- a/doc/src/sgml/ref/drop_function.sgml +++ b/doc/src/sgml/ref/drop_function.sgml @@ -1,5 +1,5 @@ @@ -8,129 +8,96 @@ PostgreSQL documentation DROP FUNCTION SQL - Language Statements + - - DROP FUNCTION - - - remove a user-defined function - + DROP FUNCTION + remove a user-defined function + - - 1999-07-20 - - + DROP FUNCTION name ( [ type [, ...] ] ) [ CASCADE | RESTRICT ] - - - - - 1998-04-15 - - - Inputs - - - - - name - - - The name (optionally schema-qualified) of an existing function. - - - - - type - - - The type of a parameter of the function. - - - - - CASCADE - - - Automatically drop objects that depend on the function - (such as operators or triggers). - - - - - RESTRICT - - - Refuse to drop the function if there are any dependent objects. - This is the default. - - - - - - - - - - 1998-04-15 - - - Outputs - - - - - - -DROP FUNCTION - - - - Message returned if the command completes successfully. - - - - - -WARNING: RemoveFunction: Function "name" ("types") does not exist - - - - This message is given if the function specified does not - exist in the current database. - - - - - - + - - - 1998-04-15 - - - Description - + + Description + - DROP FUNCTION will remove the definition of an existing + DROP FUNCTION removes the definition of an existing function. To execute this command the user must be the - owner of the function. The input argument types to the + owner of the function. The argument types to the function must be specified, since several different functions may exist with the same name and different argument lists. - - Notes + + Parameters - - Refer to - - for information on creating functions. - + + + name + + + The name (optionally schema-qualified) of an existing function. + + + + + + type + + + The data type of an argument of the function. + + + + + + CASCADE + + + Automatically drop objects that depend on the function (such as + operators or triggers). + + + + + + RESTRICT + + + Refuse to drop the function if any objects depend on it. This + is the default. + + + + + + + + Diagnostics + + + + DROP FUNCTION + + + Message returned if the command completes successfully. + + + + + + WARNING: RemoveFunction: Function name (types) does not exist + + + This message is output if the function specified does not exist. + + + + @@ -149,8 +116,8 @@ DROP FUNCTION sqrt(integer); Compatibility - A DROP FUNCTION statement is defined in SQL99. One of - its syntax forms is similar to PostgreSQL's. + A DROP FUNCTION statement is defined in the SQL + standard, but it is not compatible with this command. @@ -161,6 +128,7 @@ DROP FUNCTION sqrt(integer); + @@ -8,89 +8,60 @@ PostgreSQL documentation DROP GROUP SQL - Language Statements + - - DROP GROUP - - - remove a user group - + DROP GROUP + remove a user group + - - 2000-01-14 - - + DROP GROUP name - - - - - 2000-01-14 - - - Inputs - - - - - - name - - - The name of an existing group. - - - - - - - - - - 2000-01-14 - - - Outputs - - - - - DROP GROUP - - - The message returned if the group is successfully deleted. - - - - - - - + - - - 2000-01-14 - - - Description - + + Description + - DROP GROUP removes the specified group from the database. - The users in the group are not deleted. + DROP GROUP removes the specified group. The + users in the group are not deleted. - - Use - to add new groups, and to change a group's membership. - + + + + Parameters + + + + name + + + The name of an existing group. + + + + + + + + Diagnostics + + + + DROP GROUP + + + Message returned if the group was successfully removed. + + + + - - - Usage - + + Examples + To drop a group: @@ -99,23 +70,23 @@ DROP GROUP staff; - - - Compatibility - - - - - 2000-01-14 - - - SQL92 - - - There is no DROP GROUP in SQL92. - - + + Compatibility + + + There is no DROP GROUP statement in the SQL standard. + + + + See Also + + + + + + + @@ -8,161 +8,118 @@ PostgreSQL documentation DROP INDEX SQL - Language Statements + - - DROP INDEX - - - remove an index - + DROP INDEX + remove an index + - - 1999-07-20 - - + DROP INDEX index_name [, ...] [ CASCADE | RESTRICT ] - - - - - 1998-04-15 - - - Inputs - - - - - index_name - - - The name (optionally schema-qualified) of an index to remove. - - - - - CASCADE - - - Automatically drop objects that depend on the index. - - - - - RESTRICT - - - Refuse to drop the index if there are any dependent objects. - This is the default. - - - - - - - - - - 1998-04-15 - - - Outputs - - - - - -DROP INDEX - - - - The message returned if the command completes successfully. - - - - - -ERROR: index "index_name" does not exist - - - - This message occurs if index_name - is not an index in the database. - - - - - - + - - - 1998-04-15 - - - Description - + + Description + DROP INDEX drops an existing index from the database system. To execute this command you must be the owner of the index. - - - - 1998-04-15 - - - Notes - - - DROP INDEX is a PostgreSQL - language extension. - - - Refer to - - for information on how to create indexes. - - - - - Usage - - - This command will remove the title_idx index: + + Parameters - - DROP INDEX title_idx; - + + + index_name + + + The name (optionally schema-qualified) of an index to remove. + + + + + + CASCADE + + + Automatically drop objects that depend on the index. + + + + + + RESTRICT + + + Refuse to drop the index if any objects depend on it. This is + the default. + + + + + + + + Diagnostics + + + + DROP INDEX + + + Message returned if the command completes successfully. + + + + + + ERROR: index "index_name" does not exist + + + This message is returned if index_name is not an existing + index. + + + + + + + + Examples + + + This command will remove the index title_idx: + + +DROP INDEX title_idx; + - - - Compatibility - + + Compatibility - - - 1998-04-15 - - - SQL92 - - - SQL92 defines commands by which to access - a generic relational database. - Indexes are an implementation-dependent feature and hence - there are no index-specific commands or definitions in the - SQL92 language. - - + + DROP INDEX is a + PostgreSQL language extension. There + are no provisions for indexes in the SQL standard. + + + + See Also + + + + + + diff --git a/doc/src/sgml/ref/drop_language.sgml b/doc/src/sgml/ref/drop_language.sgml index e0690a88ac..5e7a77f8cf 100644 --- a/doc/src/sgml/ref/drop_language.sgml +++ b/doc/src/sgml/ref/drop_language.sgml @@ -1,5 +1,5 @@ @@ -8,163 +8,120 @@ PostgreSQL documentation DROP LANGUAGE SQL - Language Statements + - - DROP LANGUAGE - - - remove a user-defined procedural language - + DROP LANGUAGE + remove a user-defined procedural language + - - 1999-07-20 - - + DROP [ PROCEDURAL ] LANGUAGE name [ CASCADE | RESTRICT ] - - - - - 1998-04-15 - - - Inputs - - - - - - name - - - The name of an existing procedural language. For backward - compatibility, the name may be enclosed by single quotes. - - - - - CASCADE - - - Automatically drop objects that depend on the language - (such as functions in the language). - - - - - RESTRICT - - - Refuse to drop the language if there are any dependent objects. - This is the default. - - - - - - - - - - - 1998-04-15 - - - Outputs - - - - - -DROP LANGUAGE - - - - This message is returned if the language is successfully dropped. - - - - - -ERROR: Language "name" doesn't exist - - - - This message occurs if a language called - name is - not found in the database. - - - - - - + - - - - 1998-04-15 - - - Description - + + + Description + - DROP PROCEDURAL LANGUAGE will remove the definition + DROP LANGUAGE will remove the definition of the previously registered procedural language called name. - - - - 1998-04-15 - - - Notes - - - The DROP PROCEDURAL LANGUAGE statement is - a PostgreSQL language extension. - - - Refer to - - for information on how to create procedural languages. - - - - - - Usage - - - This command removes the PL/Sample language: + + + Parameters - + + + name + + + The name of an existing procedural language. For backward + compatibility, the name may be enclosed by single quotes. + + + + + + CASCADE + + + Automatically drop objects that depend on the language (such as + functions in the language). + + + + + + RESTRICT + + + Refuse to drop the language if any objects depend on it. This + is the default. + + + + + + + + Diagnostics + + + + DROP LANGUAGE + + + This message is returned if the language was successfully dropped. + + + + + + ERROR: Language "name" doesn't exist + + + This message is returned if a language called name is not found in the + database. + + + + + + + + Examples + + + This command removes the procedural language + plsample: + + DROP LANGUAGE plsample; - + - - - Compatibility - - - - - 1998-04-15 - - - SQL92 - - - There is no DROP PROCEDURAL LANGUAGE in - SQL92. - - + + Compatibility + + + There is no DROP LANGUAGE statement in the SQL + standard. + + + + See Also + + + + + + @@ -8,162 +8,118 @@ PostgreSQL documentation DROP OPERATOR CLASS SQL - Language Statements + - - DROP OPERATOR CLASS - - - remove a user-defined operator class - + DROP OPERATOR CLASS + remove a user-defined operator class - - 2002-07-28 - - -DROP OPERATOR CLASS name USING access_method [ CASCADE | RESTRICT ] - - - - - 2002-07-28 - - - Inputs - - - - - name - - - The name (optionally schema-qualified) of an existing operator class. - - - - - access_method - - - The name of the index access method the operator class is for. - - - - - CASCADE - - - Automatically drop objects that depend on the operator class. - - - - - RESTRICT - - - Refuse to drop the operator class if there are any dependent objects. - This is the default. - - - - - - - - - - 2002-07-28 - - - Outputs - - - - - - -DROP OPERATOR CLASS - - - - The message returned if the command is successful. - - - - - - + +DROP OPERATOR CLASS name USING index_method [ CASCADE | RESTRICT ] + - - - 2002-07-28 - - - Description - + + Description + - DROP OPERATOR CLASS drops an existing operator class - from the database. + DROP OPERATOR CLASS drops an existing operator class. To execute this command you must be the owner of the operator class. + + + + Parameters - - - 2002-07-28 - - - Notes - - - The DROP OPERATOR CLASS statement is a - PostgreSQL - language extension. - - - Refer to - - for information on how to create operator classes. - - + + + name + + + The name (optionally schema-qualified) of an existing operator class. + + + + + + index_method + + + The name of the index access method the operator class is for. + + + + + + CASCADE + + + Automatically drop objects that depend on the operator class. + + + + + + RESTRICT + + + Refuse to drop the operator class if any objects depend on it. + This is the default. + + + + - - - Usage - + + Diagnostics + + + + DROP OPERATOR CLASS + + + Message returned if the command was successful. + + + + + + + + Examples + - Remove B-tree operator class widget_ops: + Remove the B-tree operator class widget_ops: - + DROP OPERATOR CLASS widget_ops USING btree; - + - This command will not execute if there are any existing indexes + This command will not succeed if there are any existing indexes that use the operator class. Add CASCADE to drop such indexes along with the operator class. - - - Compatibility - + + Compatibility - - - 2002-07-28 - - - SQL92 - - - There is no DROP OPERATOR CLASS in - SQL92. - - + + There is no DROP OPERATOR CLASS statement in the + SQL standard. + + + + See Also + + + + + + @@ -8,216 +8,169 @@ PostgreSQL documentation DROP OPERATOR SQL - Language Statements + - - DROP OPERATOR - - - remove a user-defined operator - + DROP OPERATOR + remove a user-defined operator - - 1999-07-20 - - -DROP OPERATOR id ( lefttype | NONE , righttype | NONE ) [ CASCADE | RESTRICT ] - - - - - 1998-09-22 - - - Inputs - - - - - id - - - The identifier (optionally schema-qualified) of an existing operator. - - - - - lefttype - - - The type of the operator's left argument; write NONE if the - operator has no left argument. - - - - - righttype - - - The type of the operator's right argument; write NONE if the - operator has no right argument. - - - - - CASCADE - - - Automatically drop objects that depend on the operator. - - - - - RESTRICT - - - Refuse to drop the operator if there are any dependent objects. - This is the default. - - - - - - - - - - 1998-09-22 - - - Outputs - - - - - - -DROP OPERATOR - - - - The message returned if the command is successful. - - - - - -ERROR: RemoveOperator: binary operator 'oper' taking 'lefttype' and 'righttype' does not exist - - - - This message occurs if the specified binary operator does not exist. - - - - - -ERROR: RemoveOperator: left unary operator 'oper' taking 'lefttype' does not exist - - - - This message occurs if the left unary operator - specified does not exist. - - - - - -ERROR: RemoveOperator: right unary operator 'oper' taking 'righttype' does not exist - - - - This message occurs if the right unary operator - specified does not exist. - - - - - - + +DROP OPERATOR name ( lefttype | NONE , righttype | NONE ) [ CASCADE | RESTRICT ] + - - - 1998-09-22 - - - Description - - - DROP OPERATOR drops an existing operator from the - database. - To execute this command you must be the owner of the operator. - - - The left or right type of a left or right unary - operator, respectively, must be specified as NONE. - + + Description - - - 1998-09-22 - - - Notes - - - The DROP OPERATOR statement is a - PostgreSQL - language extension. - - - Refer to - - for information on how to create operators. - - + + DROP OPERATOR drops an existing operator from + the database system. To execute this command you must be the owner + of the operator. + + + + + Parameters + + + + name + + + The name (optionally schema-qualified) of an existing operator. + + + + + + lefttype + + + The data type of the operator's left operand; write + NONE if the operator has no left operand. + + + + + + righttype + + + The data type of the operator's right operand; write + NONE if the operator has no right operand. + + + + + + CASCADE + + + Automatically drop objects that depend on the operator. + + + + + + RESTRICT + + + Refuse to drop the operator if any objects depend on it. This + is the default. + + + + - - - Usage - - - Remove power operator a^n for int4: + + Diagnostics + + + + DROP OPERATOR + + + Message returned if the command was successful. + + + + + + ERROR: RemoveOperator: binary operator 'name' taking 'lefttype' and 'righttype' does not exist + + + This message is returned if the specified binary operator does not exist. + + + + + + ERROR: RemoveOperator: left unary operator 'name' taking 'lefttype' does not exist + + + This message is returned if the specified left unary operator + does not exist. + + + + + + ERROR: RemoveOperator: right unary operator 'name' taking 'righttype' does not exist + + + This message is returned if the specified right unary operator + does not exist. + + + + + + + + Examples - -DROP OPERATOR ^ (int4, int4); - - - Remove left unary negation operator (! b) for boolean: - -DROP OPERATOR ! (none, bool); - + Remove the power operator a^b for type integer: + +DROP OPERATOR ^ (integer, integer); + + - Remove right unary factorial operator (i !) for - int4: - -DROP OPERATOR ! (int4, none); - + Remove the left unary bitwise complement operator + ~b for type bit: + +DROP OPERATOR ~ (none, bit); + + + + + Remove the right unary factorial operator x! + for type integer: + +DROP OPERATOR ! (integer, none); + - - - Compatibility - + + Compatibility - - - 1998-09-22 - - - SQL92 - - - There is no DROP OPERATOR in SQL92. - - + + There is no DROP OPERATOR statement in the SQL standard. + + + + See Also + + + + + + @@ -8,169 +8,122 @@ PostgreSQL documentation DROP RULE SQL - Language Statements + - - DROP RULE - - - remove a rewrite rule - + DROP RULE + remove a rewrite rule + - - 1998-09-22 - - + DROP RULE name ON relation [ CASCADE | RESTRICT ] - - - - - 1998-09-22 - - - Inputs - - - - - name - - - The name of an existing rule to drop. - - - - - relation - - - The name (optionally schema-qualified) of the relation the rule - applies to. - - - - - CASCADE - - - Automatically drop objects that depend on the rule. - - - - - RESTRICT - - - Refuse to drop the rule if there are any dependent objects. - This is the default. - - - - - - - - - - - 1998-09-22 - - - Outputs - - - - - -DROP RULE - - - - Message returned if successful. - - - - - -ERROR: Rule "name" not found - - - - This message occurs if the specified rule does not exist. - - - - - - + - - - 1998-09-22 - - - Description - + + Description + - DROP RULE drops a rule from the specified - PostgreSQL rule - system. PostgreSQL - will immediately cease enforcing it and - will purge its definition from the system catalogs. + DROP RULE drops a rewrite rule. - - - - 1998-09-22 - - - Notes - - - The DROP RULE statement is a - PostgreSQL - language extension. - - - - Refer to CREATE RULE for - information on how to create rules. - - - - - - Usage - + + + Parameters + + + + name + + + The name of the rule to drop. + + + + + + relation + + + The name (optionally schema-qualified) of the table or view that + the rule applies to. + + + + + + CASCADE + + + Automatically drop objects that depend on the rule. + + + + + + RESTRICT + + + Refuse to drop the rule if any objects depend on it. This is + the default. + + + + + + + + Diagnostics + + + + DROP RULE + + + Message returned if the command was successful. + + + + + + ERROR: Rule "name" not found + + + Message if the specified rule does not exist. + + + + + + + + Examples + To drop the rewrite rule newrule: - + DROP RULE newrule ON mytable; - + - - - Compatibility - + + Compatibility - - - 1998-09-22 - - - SQL92 - - - There is no DROP RULE in SQL92. - - + + There is no DROP RULE statement in the SQL standard. + + + + See Also + + + + + + @@ -8,107 +8,23 @@ PostgreSQL documentation DROP SCHEMA SQL - Language Statements + - - DROP SCHEMA - - - remove a schema - + DROP SCHEMA + remove a schema + - - 2002-07-18 - - + DROP SCHEMA name [, ...] [ CASCADE | RESTRICT ] - - - - - - 2002-07-18 - - - Inputs - - - - - name - - - The name of a schema. - - - - - CASCADE - - - Automatically drop objects (tables, functions, etc) that are contained - in the schema. - - - - - RESTRICT - - - Refuse to drop the schema if it contains any objects. - This is the default. - - - - - - - - - - 2002-07-18 - - - Outputs - - - - - - -DROP SCHEMA - - - - The message returned if the schema is successfully dropped. - - - - - -ERROR: Schema "name" does not exist - - - - This message occurs if the specified schema does not exist. - - - - - - - + - - - 2002-07-18 - - - Description - + + Description + - DROP SCHEMA removes schemas from the data base. + DROP SCHEMA removes schemas from the database. @@ -116,54 +32,98 @@ ERROR: Schema "name" does not exist the owner can drop the schema (and thereby all contained objects) even if he does not own some of the objects within the schema. + + + + Parameters - - - 2002-07-18 - - - Notes - - - Refer to the CREATE SCHEMA statement for - information on how to create a schema. - - + + + name + + + The name of a schema. + + + + + + CASCADE + + + Automatically drop objects (tables, functions, etc.) that are + contained in the schema. + + + + + + RESTRICT + + + Refuse to drop the schema if it contains any objects. This is + the default. + + + + - - - Usage - + + Diagnostics + + + + DROP SCHEMA + + + Message returned if the schema was successfully dropped. + + + + + + ERROR: Schema "name" does not exist + + + This message is returned if the specified schema does not exist. + + + + + + + + Examples + To remove schema mystuff from the database, along with everything it contains: - + DROP SCHEMA mystuff CASCADE; - + - - - Compatibility - + + Compatibility - - - 2002-07-18 - - - SQL92 - - - DROP SCHEMA is fully compatible with - SQL92, except that the standard only allows - one schema to be dropped per command. - - + + DROP SCHEMA is fully conforming with the SQL + standard, except that the standard only allows one schema to be + dropped per command. + + + + See Also + + + + + + @@ -8,160 +8,112 @@ PostgreSQL documentation DROP SEQUENCE SQL - Language Statements + - - DROP SEQUENCE - - - remove a sequence - + DROP SEQUENCE + remove a sequence + - - 1999-07-20 - - + DROP SEQUENCE name [, ...] [ CASCADE | RESTRICT ] - - - - - - 1998-09-22 - - - Inputs - - - - - name - - - The name (optionally schema-qualified) of a sequence. - - - - - CASCADE - - - Automatically drop objects that depend on the sequence. - - - - - RESTRICT - - - Refuse to drop the sequence if there are any dependent objects. - This is the default. - - - - - - - - - - 1998-09-22 - - - Outputs - - - - - - -DROP SEQUENCE - - - - The message returned if the sequence is successfully dropped. - - - - - -ERROR: sequence "name" does not exist - - - - This message occurs if the specified sequence does not exist. - - - - - - - + - - - 1998-09-22 - - - Description - - - DROP SEQUENCE removes sequence number generators from the - data base. With the current implementation of sequences as - special tables it works just like the DROP TABLE - statement. - + + Description - - - 1998-09-22 - - - Notes - - - The DROP SEQUENCE statement is a - PostgreSQL - language extension. - - - Refer to the CREATE SEQUENCE statement for - information on how to create a sequence. - - + + DROP SEQUENCE removes sequence number generators. + + + + + Parameters + + + + name + + + The name (optionally schema-qualified) of a sequence. + + + + + + CASCADE + + + Automatically drop objects that depend on the sequence. + + + + + + RESTRICT + + + Refuse to drop the sequence if any objects depend on it. This + is the default. + + + + - - - Usage - - - To remove sequence serial from database: + + Diagnostics - + + + DROP SEQUENCE + + + Message returned if the sequence was successfully dropped. + + + + + + ERROR: sequence "name" does not exist + + + Message returned if the specified sequence does not exist. + + + + + + + + Examples + + + To remove the sequence serial: + + DROP SEQUENCE serial; - + - - - Compatibility - - - - - 1998-09-22 - - - SQL92 - - - There is no DROP SEQUENCE in SQL92. - - + + Compatibility + + + There is no DROP SEQUENCE statement in the SQL standard. + + + + See Also + + + + + + @@ -8,158 +8,126 @@ PostgreSQL documentation DROP TABLE SQL - Language Statements + - - DROP TABLE - - - remove a table - + DROP TABLE + remove a table + - - 1999-07-20 - - + DROP TABLE name [, ...] [ CASCADE | RESTRICT ] - - - - - - 1998-09-22 - - - Inputs - - - - - name - - - The name (optionally schema-qualified) of an existing table to drop. - - - - - CASCADE - - - Automatically drop objects that depend on the table - (such as views). - - - - - RESTRICT - - - Refuse to drop the table if there are any dependent objects. - This is the default. - - - - - - - - - - 1998-09-22 - - - Outputs - - - - - -DROP TABLE - - - - The message returned if the command completes successfully. - - - - - -ERROR: table "name" does not exist - - - - If the specified table does not exist in the database. - - - - - - + - - - 1998-09-22 - - - Description - + + Description + DROP TABLE removes tables from the database. - Only its owner may destroy a table. A table may be emptied of rows, but not - destroyed, by using DELETE. + Only its owner may destroy a table. To empty a table of rows, + without destroying the table, use DELETE. + DROP TABLE always removes any indexes, rules, - triggers, and constraints that exist for the target table. However, - to drop a table that is referenced by a foreign-key constraint of another - table, CASCADE must be specified. (CASCADE will remove the foreign-key - constraint, not the other table itself.) + triggers, and constraints that exist for the target table. + However, to drop a table that is referenced by a foreign-key + constraint of another table, CASCADE must be + specified. (CASCADE will remove the foreign-key + constraint, not the other table entirely.) + + + + Parameters - - - 1998-09-22 - - - Notes - - - Refer to CREATE TABLE and - ALTER TABLE for information on - how to create or modify tables. - - + + + name + + + The name (optionally schema-qualified) of the table to drop. + + + + + + CASCADE + + + Automatically drop objects that depend on the table (such as + views). + + + + + + RESTRICT + + + Refuse to drop the table if any objects depend on it. This is + the default. + + + + - - - Usage - + + Diagnostics + + + + DROP TABLE + + + Message returned if the command completes successfully. + + + + + + ERROR: table "name" does not exist + + + Message returned if the specified table does not exist. + + + + + + + + Examples + To destroy two tables, films and distributors: - + DROP TABLE films, distributors; - + - - - Compatibility - - - - - SQL92 - - - - + + Compatibility + + + This command conforms to the SQL standard. + + + + See Also + + + + + + + @@ -8,124 +8,102 @@ PostgreSQL documentation DROP TRIGGER SQL - Language Statements + - - DROP TRIGGER - - - remove a trigger - + DROP TRIGGER + remove a trigger + - - 1998-09-22 - - + DROP TRIGGER name ON table [ CASCADE | RESTRICT ] - - - - - 1998-09-22 - - - Inputs - - - - - - name - - - The name of an existing trigger. - - - - - table - - - The name (optionally schema-qualified) of a table. - - - - - CASCADE - - - Automatically drop objects that depend on the trigger. - - - - - RESTRICT - - - Refuse to drop the trigger if there are any dependent objects. - This is the default. - - - - - - - - - - 1998-09-22 - - - Outputs - - - - - - -DROP TRIGGER - - - - The message returned if the trigger is successfully dropped. - - - - - -ERROR: DropTrigger: there is no trigger name on relation "table" - - - - This message occurs if the trigger specified does not exist. - - - - - - + - - - 1998-09-22 - - - Description - + + Description + DROP TRIGGER will remove an existing - trigger definition. To execute this command the current + trigger definition. To execute this command, the current user must be the owner of the table for which the trigger is defined. + + Parameters + + + + name + + + The name of the trigger to remove. + + + + + + table + + + The name (optionally schema-qualified) of a table for which the + trigger is defined. + + + + + + CASCADE + + + Automatically drop objects that depend on the trigger. + + + + + + RESTRICT + + + Refuse to drop the trigger if any objects depend on it. This is + the default. + + + + + + + + Diagnostics + + + + DROP TRIGGER + + + Message returned if the trigger was successfully dropped. + + + + + + ERROR: DropTrigger: there is no trigger name on relation "table" + + + Message returned if the specified trigger does not exist. + + + + + + Examples - Destroy the if_dist_exists trigger - on table films: + Destroy the trigger if_dist_exists on the table + films: DROP TRIGGER if_dist_exists ON films; @@ -136,30 +114,13 @@ DROP TRIGGER if_dist_exists ON films; Compatibility - - - SQL92 - - - There is no DROP TRIGGER statement in - SQL92. - - - - - - SQL99 - - - The DROP TRIGGER statement in - PostgreSQL is incompatible with - SQL99. In SQL99, trigger names are not local to tables, so the - command is simply DROP TRIGGER - name. - - - - + + The DROP TRIGGER statement in + PostgreSQL is incompatible with the SQL + standard. In the SQL standard, trigger names are not local to + tables, so the command is simply DROP TRIGGER + name. + @@ -169,6 +130,7 @@ DROP TRIGGER if_dist_exists ON films; + @@ -8,118 +8,91 @@ PostgreSQL documentation DROP TYPE SQL - Language Statements + - - DROP TYPE - - - remove a user-defined data type - + DROP TYPE + remove a user-defined data type + - - 1999-07-20 - - + DROP TYPE typename [, ...] [ CASCADE | RESTRICT ] - - - - - - 1998-09-22 - - - Inputs - - - - - typename - - - The name (optionally schema-qualified) of an existing type. - - - - - CASCADE - - - Automatically drop objects that depend on the type - (such as table columns, functions, operators, etc). - - - - - RESTRICT - - - Refuse to drop the type if there are any dependent objects. - This is the default. - - - - - - - - - - 1998-09-22 - - - Outputs - - - - - -DROP TYPE - - - - The message returned if the command is successful. - - - - - -ERROR: RemoveType: type 'typename' does not exist - - - - This message occurs if the specified type is not found. - - - - - - - + - - - 1998-09-22 - - - Description - - - DROP TYPE will remove a user type from the - system catalogs. - + + Description + + DROP TYPE will remove a user-defined data type. Only the owner of a type can remove it. + + Parameters + + + + typename + + + The name (optionally schema-qualified) of the data type to remove. + + + + + + CASCADE + + + Automatically drop objects that depend on the type (such as + table columns, functions, operators). + + + + + + RESTRICT + + + Refuse to drop the type if any objects depend on it. This is + the default. + + + + + + + + Diagnostics + + + + DROP TYPE + + + Message returned if the command was successful. + + + + + + ERROR: RemoveType: type 'typename' does not exist + + + Message returned if the specified type does not exist. + + + + + + Examples - - To remove the box type: + + To remove the data type box: DROP TYPE box; @@ -130,9 +103,10 @@ DROP TYPE box; Compatibility - Note that the CREATE TYPE command and the data - type extension mechanisms in PostgreSQL - differ from SQL99. + This command is similar to the corresponding command in the SQL + standard, but note that the CREATE TYPE command + and the data type extension mechanisms in + PostgreSQL differ from the SQL standard. @@ -143,6 +117,7 @@ DROP TYPE box; + @@ -8,6 +8,7 @@ PostgreSQL documentation DROP USER SQL - Language Statements + DROP USER remove a database user account @@ -23,40 +24,36 @@ DROP USER name Description - DROP USER removes the specified user from the database. + DROP USER removes the specified user. It does not remove tables, views, or other objects owned by the user. If the user owns any database, an error is raised. + - - Parameters - - - - - name - - - The name of an existing user. - - - - - - + + Parameters + + + name + + + The name of the user to remove. + + + + Diagnostics - DROP USER - The message returned if the user is successfully deleted. + Message returned if the user was successfully deleted. @@ -65,7 +62,7 @@ DROP USER name ERROR: DROP USER: user "name" does not exist - This message occurs if the user name is not found. + Message returned if the specified user does not exist. @@ -78,18 +75,13 @@ DROP USER name - - Notes - Use - to add new users, and to change a user's attributes. PostgreSQL includes a program that has the same functionality as this command (in fact, it calls this command) @@ -122,9 +114,8 @@ DROP USER jonathan; See Also - - + diff --git a/doc/src/sgml/ref/drop_view.sgml b/doc/src/sgml/ref/drop_view.sgml index 9b35d88c04..fd32f92f8a 100644 --- a/doc/src/sgml/ref/drop_view.sgml +++ b/doc/src/sgml/ref/drop_view.sgml @@ -1,5 +1,5 @@ @@ -8,154 +8,113 @@ PostgreSQL documentation DROP VIEW SQL - Language Statements + - - DROP VIEW - - - remove a view - + DROP VIEW + remove a view + - - 1999-07-20 - - + DROP VIEW name [, ...] [ CASCADE | RESTRICT ] - - - - - 1998-09-22 - - - Inputs - - - - - - name - - - The name (optionally schema-qualified) of an existing view. - - - - - CASCADE - - - Automatically drop objects that depend on the view - (such as other views). - - - - - RESTRICT - - - Refuse to drop the view if there are any dependent objects. - This is the default. - - - - - - - - - - - 1998-09-22 - - - Outputs - - - - - - -DROP VIEW - - - - The message returned if the command is successful. - - - - - -ERROR: view name does not exist - - - - This message occurs if the specified view does not exist in - the database. - - - - - - + - - - 1998-09-22 - - - Description - - - DROP VIEW drops an existing view from the database. - To execute this command you must be the owner of the - view. - + + Description - - - 1998-09-22 - - - Notes - - - Refer to - for information on how to create views. - - + + DROP VIEW drops an existing view. To execute + this command you must be the owner of the view. + + + + + Parameters + + + + name + + + The name (optionally schema-qualified) of the view to remove. + + + + + + CASCADE + + + Automatically drop objects that depend on the view (such as + other views). + + + + + + RESTRICT + + + Refuse to drop the view if any objects depend on it. This is + the default. + + + + - - - Usage - + + Diagnostics + + + + DROP VIEW + + + Message returned if the command was successful. + + + + + + ERROR: view name does not exist + + + Message returned if the specified view does not exist. + + + + + + + + Examples + This command will remove the view called kinds: - - + DROP VIEW kinds; - + + - - - Compatibility - - - - - 1998-09-22 - - - SQL92 - - - - + + Compatibility + + + This command conforms to the SQL standard. + + + + See Also + + + + + + @@ -8,19 +8,14 @@ PostgreSQL documentation FETCH SQL - Language Statements + - - FETCH - - - retrieve rows from a query using a cursor - + FETCH + retrieve rows from a query using a cursor + - - 2003-03-11 - - + FETCH [ direction { FROM | IN } ] cursor where direction can be empty or one of: @@ -39,243 +34,20 @@ where direction can be empty or one BACKWARD BACKWARD count BACKWARD ALL - - - - - 2003-03-11 - - - Inputs - - - - - - direction - - - direction - defines the fetch direction and number of rows to fetch. - It can be one of the following: - - - - NEXT - - - fetch next row. This is the default - if direction is omitted. - - - - - - PRIOR - - - fetch prior row. - - - - - - FIRST - - - fetch first row of query (same as ABSOLUTE 1). - - - - - - LAST - - - fetch last row of query (same as ABSOLUTE -1). - - - - - - ABSOLUTE count - - - fetch the count'th - row of query, or the - abs(count)'th row - from the end if - count < 0. - Position before first row or after last row - if count is out of - range; in particular, ABSOLUTE 0 positions before first row. - - - - - - RELATIVE count - - - fetch the count'th - succeeding row, or the - abs(count)'th prior - row if count < 0. - RELATIVE 0 re-fetches current row, if any. - - - - - - count - - - fetch the next count - rows (same as FORWARD count). - - - - - - ALL - - - fetch all remaining rows (same as FORWARD ALL). - - - - - - FORWARD - - - fetch next row (same as NEXT). - - - - - - FORWARD count - - - fetch next count - rows. FORWARD 0 re-fetches current row. - - - - - - FORWARD ALL - - - fetch all remaining rows. - - - - - - BACKWARD - - - fetch prior row (same as PRIOR). - - - - - - BACKWARD count - - - fetch prior count - rows (scanning backwards). BACKWARD 0 re-fetches current row. - - - - - - BACKWARD ALL - - - fetch all prior rows (scanning backwards). - - - - - - - - - - - count - - - count - is a possibly-signed integer constant, determining the location - or number of rows to fetch. For FORWARD and BACKWARD cases, - specifying a negative count - is equivalent to changing the sense of FORWARD and BACKWARD. - - - - - - cursor - - - An open cursor's name. - - - - - - - - - - 2003-03-11 - - - Outputs - - - FETCH returns rows from the result of the query defined - by the specified cursor. - The following messages will be returned if the query fails: - - - - -WARNING: PerformPortalFetch: portal "cursor" not found - - - - There is no cursor with the specified name. - - - - - - + - - - 2003-03-11 - - - Description - + + Description FETCH retrieves rows using a cursor. - A cursor has an associated position that is used by + A cursor has an associated position, which is used by FETCH. The cursor position can be before the first row of the - query result, or on any particular row of the result, or after the last row + query result, on any particular row of the result, or after the last row of the result. When created, a cursor is positioned before the first row. After fetching some rows, the cursor is positioned on the row most recently retrieved. If FETCH runs off the end of the available rows @@ -286,166 +58,338 @@ WARNING: PerformPortalFetch: portal "cursor - The SQL-compatible forms (NEXT, PRIOR, FIRST, LAST, ABSOLUTE, RELATIVE) - fetch a single row after moving the cursor appropriately. If there is - no such row, an empty result is returned, and the cursor is left positioned - before the first row or after the last row as appropriate. + The forms NEXT, PRIOR, FIRST, + LAST, ABSOLUTE, RELATIVE fetch + a single row after moving the cursor appropriately. If there is no + such row, an empty result is returned, and the cursor is left + positioned before the first row or after the last row as + appropriate. - The forms using FORWARD and BACKWARD are not in the SQL standard, but - are PostgreSQL extensions. These forms - retrieve the indicated number of rows moving in the forward or backward - direction, leaving the cursor positioned on the last-returned row - (or after/before all rows, if the FORWARD and BACKWARD + retrieve the indicated number of rows moving in the forward or + backward direction, leaving the cursor positioned on the + last-returned row (or after/before all rows, if the count exceeds the number of rows available). - - - RELATIVE 0, FORWARD 0, and BACKWARD 0 all request - fetching the current row without moving the - cursor --- that is, re-fetching the most recently fetched row. - This will succeed unless the cursor is positioned before the - first row or after the last row; in which case, no row is returned. - - - - - - 2003-03-11 - - - Notes - - - - The cursor should be declared with the SCROLL option if one intends to - use any variants of FETCH other than FETCH NEXT - or FETCH FORWARD with a positive count. For simple queries - PostgreSQL will allow backwards fetch from - cursors not declared with SCROLL, but this behavior is best not - relied on. If the cursor is declared with NO SCROLL, no backward - fetches are allowed. - - - - ABSOLUTE fetches are not any faster than navigating to the desired row - with a relative move: the underlying implementation must traverse all - the intermediate rows anyway. Negative absolute fetches are even worse: - the query must be read to the end to find the last row, and then - traversed backward from there. However, rewinding to the start of the - query (as with FETCH ABSOLUTE 0) is fast. - - - - Updating data via a cursor is not supported by - PostgreSQL, because mapping cursor - updates back to base tables is not generally possible, as is also - the case with view updates. Consequently, users must issue - explicit UPDATE commands to replace data. - - - - - is used to define a cursor. - Use - - to change cursor position without retrieving data. - - + + RELATIVE 0, FORWARD 0, and + BACKWARD 0 all request fetching the current row without + moving the cursor, that is, re-fetching the most recently fetched + row. This will succeed unless the cursor is positioned before the + first row or after the last row; in which case, no row is returned. + - - - Usage - + + Parameters + + + + direction + + + direction defines + the fetch direction and number of rows to fetch. It can be one + of the following: + + + + NEXT + + + Fetch the next row. This is the default if direction is omitted. + + + + + + PRIOR + + + Fetch the prior row. + + + + + + FIRST + + + Fetch the first row of the query (same as ABSOLUTE 1). + + + + + + LAST + + + Fetch the last row of the query (same as ABSOLUTE -1). + + + + + + ABSOLUTE count + + + Fetch the count'th row of the query, + or the abs(count)'th row from + the end if count is negative. Position + before first row or after last row if count is out of range; in + particular, ABSOLUTE 0 positions before + the first row. + + + + + + RELATIVE count + + + Fetch the count'th succeeding row, or + the abs(count)'th prior + row if count is + negative. RELATIVE 0 re-fetches the + current row, if any. + + + + + + count + + + Fetch the next count rows (same as + FORWARD count). + + + + + + ALL + + + Fetch all remaining rows (same as FORWARD ALL). + + + + + + FORWARD + + + Fetch the next row (same as NEXT). + + + + + + FORWARD count + + + Fetch the next count rows. + FORWARD 0 re-fetches the current row. + + + + + + FORWARD ALL + + + Fetch all remaining rows. + + + + + + BACKWARD + + + Fetch the prior row (same as PRIOR). + + + + + + BACKWARD count + + + Fetch the prior count rows (scanning + backwards). BACKWARD 0 re-fetches the + current row. + + + + + + BACKWARD ALL + + + Fetch all prior rows (scanning backwards). + + + + + + + + + + count + + + count is a + possibly-signed integer constant, determining the location or + number of rows to fetch. For FORWARD and + BACKWARD cases, specifying a negative count is equivalent to changing + the sense of FORWARD and BACKWARD. + + + + + + cursor + + + An open cursor's name. + + + + + + + + Diagnostics + + + + WARNING: PerformPortalFetch: portal "cursor" not found + + + There is no cursor with the specified name. + + + + + + + + Notes + + + The cursor should be declared with the SCROLL + option if one intends to use any variants of FETCH + other than FETCH NEXT or FETCH FORWARD with + a positive count. For simple queries + PostgreSQL will allow backwards fetch + from cursors not declared with SCROLL, but this + behavior is best not relied on. If the cursor is declared with + NO SCROLL, no backward fetches are allowed. + + + + ABSOLUTE fetches are not any faster than + navigating to the desired row with a relative move: the underlying + implementation must traverse all the intermediate rows anyway. + Negative absolute fetches are even worse: the query must be read to + the end to find the last row, and then traversed backward from + there. However, rewinding to the start of the query (as with + FETCH ABSOLUTE 0) is fast. + + + + Updating data via a cursor is currently not supported by + PostgreSQL. + + + + + is used to define a cursor. Use + + to change cursor position without retrieving data. + + + + + Examples The following example traverses a table using a cursor. --- Set up and use a cursor: - BEGIN WORK; + +-- Set up a cursor: DECLARE liahona SCROLL CURSOR FOR SELECT * FROM films; --- Fetch first 5 rows in the cursor liahona: -FETCH FORWARD 5 IN liahona; +-- Fetch the first 5 rows in the cursor liahona: +FETCH FORWARD 5 FROM liahona; - - code | title | did | date_prod | kind | len + code | title | did | date_prod | kind | len -------+-------------------------+-----+------------+----------+------- BL101 | The Third Man | 101 | 1949-12-23 | Drama | 01:44 BL102 | The African Queen | 101 | 1951-08-11 | Romantic | 01:43 JL201 | Une Femme est une Femme | 102 | 1961-03-12 | Romantic | 01:25 P_301 | Vertigo | 103 | 1958-11-14 | Action | 02:08 P_302 | Becket | 103 | 1964-02-03 | Drama | 02:28 - --- Fetch previous row: +-- Fetch the previous row: FETCH PRIOR FROM liahona; - - code | title | did | date_prod | kind | len + code | title | did | date_prod | kind | len -------+---------+-----+------------+--------+------- P_301 | Vertigo | 103 | 1958-11-14 | Action | 02:08 - - --- close the cursor and commit work: +-- Close the cursor and end the transaction: CLOSE liahona; COMMIT WORK; - - - Compatibility - + + Compatibility - - - 2003-03-11 - - - SQL92 - + + The SQL standard defines FETCH for use in + embedded SQL only. This variant of FETCH + described here returns the data as if it were a + SELECT result rather than placing it in host + variables. Other than this point, FETCH is + fully upward-compatible with the SQL standard. + - - SQL92 defines FETCH for use - in embedded contexts only. Therefore, it describes placing the - results into explicit variables using an INTO clause, - for example: + + The FETCH forms involving + FORWARD and BACKWARD, as well + as the forms FETCH count and FETCH + ALL, in which FORWARD is implicit, are + PostgreSQL extensions. + - -FETCH ABSOLUTE n - FROM cursor - INTO :variable [, ...] - - - PostgreSQL's use of non-embedded - cursors is non-standard, and so is its practice of returning the - result data as if it were a SELECT result. - Other than this point, FETCH is fully - upward-compatible with SQL92. - - - - The FETCH forms involving FORWARD and BACKWARD - (including the forms FETCH count and FETCH ALL, in which - FORWARD is implicit) are PostgreSQL - extensions. - - - - SQL92 allows only FROM preceding the - cursor name; the option to use IN is an extension. - - + + The SQL standard allows only FROM preceding the cursor + name; the option to use IN is an extension. + diff --git a/doc/src/sgml/ref/move.sgml b/doc/src/sgml/ref/move.sgml index cd6d6aca0f..d60ec29c3b 100644 --- a/doc/src/sgml/ref/move.sgml +++ b/doc/src/sgml/ref/move.sgml @@ -1,5 +1,5 @@ @@ -8,112 +8,74 @@ PostgreSQL documentation MOVE SQL - Language Statements + - - MOVE - - - reposition a cursor - - + MOVE + reposition a cursor + + - - 1999-07-20 - - + MOVE [ direction { FROM | IN } ] cursor - + - - - 1998-09-24 - - - Description - + + Description + MOVE repositions a cursor without retrieving any data. MOVE works exactly like the FETCH command, except it only repositions the cursor and does not return rows. + Refer to for details on syntax and usage. - - - - 1998-09-24 - - - Notes - - - - The count returned in MOVE's status string is the - count of the number of rows that would have been returned by the - equivalent FETCH command. - - - - Refer to - - for a description of valid arguments. - Refer to - - to define a cursor. - - - - - Usage - + + Diagnostics + - Set up and use a cursor: + The count returned in MOVE's status string is + the count of the number of rows that would have been returned by + the equivalent FETCH command. + + + + + Examples BEGIN WORK; DECLARE liahona CURSOR FOR SELECT * FROM films; --- Skip first 5 rows: + +-- Skip the first 5 rows: MOVE FORWARD 5 IN liahona; - MOVE 5 - --- Fetch 6th row in the cursor liahona: -FETCH 1 IN liahona; - - code | title | did | date_prod | kind | len --------+--------+-----+-----------+--------+------- - P_303 | 48 Hrs | 103 | 1982-10-22| Action | 01:37 + +-- Fetch the 6th row from the cursor liahona: +FETCH 1 FROM liahona; + code | title | did | date_prod | kind | len +-------+--------+-----+------------+--------+------- + P_303 | 48 Hrs | 103 | 1982-10-22 | Action | 01:37 (1 row) - --- close the cursor liahona and commit work: + +-- Close the cursor liahona and end the transaction: CLOSE liahona; COMMIT WORK; - - - - Compatibility - + + Compatibility - - - 1998-09-01 - - - SQL92 - - - There is no SQL92 MOVE statement. - - + + There is no MOVE statement in the SQL standard. + diff --git a/doc/src/sgml/ref/reset.sgml b/doc/src/sgml/ref/reset.sgml index bb6860657d..87d9de3097 100644 --- a/doc/src/sgml/ref/reset.sgml +++ b/doc/src/sgml/ref/reset.sgml @@ -1,5 +1,5 @@ @@ -8,95 +8,97 @@ PostgreSQL documentation RESET SQL - Language Statements + RESET - restore the value of a run-time parameter to a default value + restore the value of a run-time parameter to the default value + - -RESET variable - - + +RESET parameter + + RESET ALL - - - - Inputs - - - - variable - - - The name of a run-time parameter. See for a list. - - - - - ALL - - - Resets all settable run-time parameters to default values. - - - - - - - + Description + RESET restores run-time parameters to their - default values. Refer to - - for details. RESET is an alternate spelling for - - -SET variable TO DEFAULT - - - The default value is defined as the value that the variable would - have had, had no SET ever been issued for it in the - current session. The actual source of this value might be a - compiled-in default, the postmaster's configuration file or command-line - switches, or per-database or per-user default settings. See - for details. + default values. RESET is an alternative + spelling for + +SET parameter TO DEFAULT + + Refer to for + details. - See the SET manual page for details on the transaction - behavior of RESET. + The default value is defined as the value that the parameter would + have had, had no SET ever been issued for it in the + current session. The actual source of this value might be a + compiled-in default, the configuration file, command-line options, + or per-database or per-user default settings. See for details. + + See the SET reference page for details on the + transaction behavior of RESET. + + + + + Parameters + + + + parameter + + + The name of a run-time parameter. See for a list. + + + + + + ALL + + + Resets all settable run-time parameters to default values. + + + + Diagnostics + - See under the command. + See under the . Examples - - Set DateStyle to its default value: + + Set datestyle to its default value: -RESET DateStyle; +RESET datestyle; Set geqo to its default value: - - -RESET GEQO; + +RESET geqo; diff --git a/doc/src/sgml/ref/select.sgml b/doc/src/sgml/ref/select.sgml index 6362840ec0..f983b2a821 100644 --- a/doc/src/sgml/ref/select.sgml +++ b/doc/src/sgml/ref/select.sgml @@ -1,5 +1,5 @@ @@ -8,667 +8,666 @@ PostgreSQL documentation SELECT SQL - Language Statements + - - SELECT - - - retrieve rows from a table or view - + SELECT + retrieve rows from a table or view + + - - 2000-12-11 - - -SELECT [ ALL | DISTINCT [ ON ( expression [, ...] ) ] ] - * | expression [ AS output_name ] [, ...] - [ FROM from_item [, ...] ] - [ WHERE condition ] - [ GROUP BY expression [, ...] ] - [ HAVING condition [, ...] ] - [ { UNION | INTERSECT | EXCEPT } [ ALL ] select ] - [ ORDER BY expression [ ASC | DESC | USING operator ] [, ...] ] - [ LIMIT { count | ALL } ] - [ OFFSET start ] - [ FOR UPDATE [ OF tablename [, ...] ] ] + +SELECT [ ALL | DISTINCT [ ON ( expression [, ...] ) ] ] + * | expression [ AS output_name ] [, ...] + [ FROM from_item [, ...] ] + [ WHERE condition ] + [ GROUP BY expression [, ...] ] + [ HAVING condition [, ...] ] + [ { UNION | INTERSECT | EXCEPT } [ ALL ] select ] + [ ORDER BY expression [ ASC | DESC | USING operator ] [, ...] ] + [ LIMIT { count | ALL } ] + [ OFFSET start ] + [ FOR UPDATE [ OF table_name [, ...] ] ] -where from_item can be: +where from_item can be one of: -[ ONLY ] table_name [ * ] - [ [ AS ] alias [ ( column_alias_list ) ] ] -| -( select ) - [ AS ] alias [ ( column_alias_list ) ] -| -table_function_name ( [ argument [, ...] ] ) - [ AS ] alias [ ( column_alias_list | column_definition_list ) ] -| -table_function_name ( [ argument [, ...] ] ) - AS ( column_definition_list ) -| - -from_item [ NATURAL ] join_type from_item - [ ON join_condition | USING ( join_column_list ) ] - - - - - 2000-12-11 - - - Inputs - + [ ONLY ] table_name [ * ] [ [ AS ] alias [ ( column_alias [, ...] ) ] ] + ( select ) [ AS ] alias [ ( column_alias [, ...] ) ] + function_name ( [ argument [, ...] ] ) [ AS ] alias [ ( column_alias [, ...] | column_definition [, ...] ) ] + function_name ( [ argument [, ...] ] ) AS ( column_definition [, ...] ) + from_item [ NATURAL ] join_type from_item [ ON join_condition | USING ( join_column [, ...] ) ] + - - - - expression - - - The name of a table's column or an expression. - - - - - - output_name - - - Specifies another name for an output column using - the AS clause. This name is primarily used to label the column - for display. It can also be used to refer to the column's value in - ORDER BY and GROUP BY clauses. But the - output_name - cannot be used in the WHERE or HAVING clauses; write out the - expression instead. - - - - - - from_item - - - A table reference, sub-SELECT, table function, or JOIN clause. See below for details. - - - - - - condition - - - A Boolean expression giving a result of true or false. - See the WHERE and HAVING clause descriptions below. - - - - - - select - - - A select statement with all features except the ORDER BY, - LIMIT/OFFSET, and FOR UPDATE clauses (even those can be used when the - select is parenthesized). - - - - - - +FIXME: This last syntax is incorrect if the join type is an +INNER or OUTER join (in which case one of NATURAL, ON ..., or USING +... is mandatory, not optional). What's the best way to fix +this? - - FROM items can contain: - - - - table_name - - - The name (optionally schema-qualified) of an existing table or view. - If ONLY is specified, only that table is scanned. If - ONLY is not specified, the table and all its descendant - tables (if any) are scanned. * can be appended to the - table name to indicate that descendant tables are to be scanned, but - in the current version, this is the default behavior. (In releases - before 7.1, ONLY was the default behavior.) The - default behavior can be modified by changing the - configuration option. - - - - - - alias - - - A substitute name for the FROM item containing the alias. - An alias is used for brevity or to eliminate ambiguity for self-joins - (where the same table is scanned multiple times). When an alias - is provided, it completely hides the actual name of the table or - table function; for example given FROM foo AS f, the - remainder of the SELECT must refer to this FROM item as f - not foo. - If an alias is - written, a column alias list can also be written to provide - substitute names for one or more columns of the table. - - - - - - select - - - A sub-SELECT can appear in the FROM clause. This acts as though - its output were created as a temporary table for the duration of - this single SELECT command. Note that the sub-SELECT must be - surrounded by parentheses, and an alias must - be provided for it. - - - - - - table function - - - A table function can appear in the FROM clause. This acts as though - its output were created as a temporary table for the duration of - this single SELECT command. An alias may also be used. If an alias is - written, a column alias list can also be written to provide substitute - names for one or more columns of the table function. If the table - function has been defined as returning the record data type, - an alias, or the keyword AS, must be present, followed by - a column definition list in the form ( column_name data_type [, ... ] ). - The column definition list must match the actual number and types - of columns returned by the function. - - - - - - join_type - - - One of - [ INNER ] JOIN, - LEFT [ OUTER ] JOIN, - RIGHT [ OUTER ] JOIN, - FULL [ OUTER ] JOIN, or - CROSS JOIN. - For INNER and OUTER join types, exactly one of NATURAL, - ON join_condition, or - USING ( join_column_list ) - must appear. For CROSS JOIN, none of these items may appear. - - - - - - join_condition - - - A qualification condition. This is similar to the WHERE condition - except that it only applies to the two from_items being joined in - this JOIN clause. - - - - - - join_column_list - - - A USING column list ( a, b, ... ) is shorthand for the ON condition - left_table.a = right_table.a AND left_table.b = right_table.b ... - - - - - - - - - - - 1998-09-24 - - - Outputs - - - - - - Rows - - - The complete set of rows resulting from the query specification. - - - - - - - count - - - - The count of rows returned by the query. - - - - - - - - - 2000-12-11 - - - Description - - - SELECT will return rows from one or more tables. - Candidates for selection are rows which satisfy the WHERE condition; - if WHERE is omitted, all rows are candidates. - (See .) - + + Description - Actually, the returned rows are not directly the rows produced by the - FROM/WHERE/GROUP BY/HAVING clauses; rather, the output rows are formed - by computing the SELECT output expressions for each selected row. - * can be written in the output list as a shorthand - for all the columns of the selected rows. Also, one can write - table_name.* - as a shorthand for the columns coming from just that table. - + SELECT retrieves rows from one or more tables. + The general processing of SELECT is as follows: - - DISTINCT will eliminate duplicate rows from the result. ALL (the - default) will return all candidate rows, including duplicates. - + + + + All elements in the FROM list are computed. + (Each element in the FROM list is a real or + virtual table.) If more than one element is specified in the + FROM list, they are cross-joined together. + (See below.) + + - - DISTINCT ON eliminates rows that match on all the - specified expressions, keeping only the first row of each set of - duplicates. The DISTINCT ON expressions are interpreted using the - same rules as for ORDER BY items; see below. - Note that the first row of each set is unpredictable - unless ORDER BY is used to ensure that the desired - row appears first. For example, - - SELECT DISTINCT ON (location) location, time, report - FROM weatherReports - ORDER BY location, time DESC; - - retrieves the most recent weather report for each location. But if - we had not used ORDER BY to force descending order of time values - for each location, we'd have gotten a report of unpredictable age - for each location. - + + + If the WHERE clause is specified, all rows + that do not satisfy the condition are eliminated from the + output. (See below.) + + - - The GROUP BY clause allows a user to divide a table - into groups of rows that match on one or more values. - (See .) - + + + If the GROUP BY clause is specified, the + output is divided into groups of rows that match on one or more + values. If the HAVING clause is present, it + eliminates groups that do not satisfy the given condition. (See + and + below.) + + - - The HAVING clause allows selection of only those groups of rows - meeting the specified condition. - (See .) - - - - The ORDER BY clause causes the returned rows to be sorted in a specified - order. If ORDER BY is not given, the rows are returned in whatever order - the system finds cheapest to produce. - (See .) - - - - SELECT queries can be combined using UNION, - INTERSECT, and EXCEPT operators. Use parentheses if necessary to - determine the ordering of these operators. - - - - The UNION operator computes the collection of rows - returned by the queries involved. - Duplicate rows are eliminated unless ALL is specified. - (See .) - - - - The INTERSECT operator computes the rows that are common to both queries. - Duplicate rows are eliminated unless ALL is specified. - (See .) - - - - The EXCEPT operator computes the rows returned by the first query but - not the second query. - Duplicate rows are eliminated unless ALL is specified. - (See .) - - - - The LIMIT clause allows a subset of the rows produced by the query - to be returned to the user. - (See .) - + + + Using the operators UNION, + INTERSECT, and EXCEPT, the + output of more than one SELECT statement can + be combined to form a single result set. The + UNION operator returns all rows that are in + one or both of the result sets. The + INTERSECT operator returns all rows that are + strictly in both result sets. The EXCEPT + operator returns the rows that are in the first result set but + not in the second. In all three cases, duplicate rows are + eliminated unless ALL is specified. (See + , , and + below.) + + - - The FOR UPDATE clause causes the SELECT - statement to lock the selected rows against concurrent updates. + + + The actual output rows are computed the + SELECT output expressions for each selected + row. (See + + below.) + + + + + + If the ORDER BY clause is specified, the + returned rows are sorted in the specified order. If + ORDER BY is not given, the rows are returned + in whatever order the system finds fastest to produce. (See + below.) + + + + + + If the LIMIT or OFFSET + clause is specified, the SELECT statement + only returns a subset of the result rows. (See below.) + + + + + + DISTINCT eliminates duplicate rows from the + result. DISTINCT ON eliminates rows that + match on all the specified expressions. ALL + (the default) will return all candidate rows, including + duplicates. (See below.) + + + + + + The FOR UPDATE clause causes the + SELECT statement to lock the selected rows + against concurrent updates. (See below.) + + + - You must have SELECT privilege to a table to read its values - (See the GRANT/REVOKE statements). - Use of FOR UPDATE requires UPDATE privilege as well. + You must have SELECT privilege on a table to + read its values. The use of FOR UPDATE requires + UPDATE privilege as well. - + + + + Parameters + - - 2000-12-11 - - - FROM Clause - + <literal>FROM</literal> Clause - The FROM clause specifies one or more source tables for the - SELECT. If multiple sources are specified, the - result is conceptually the Cartesian product of all the rows in - all the sources --- but usually qualification conditions are added - to restrict the returned rows to a small subset of the Cartesian - product. + The FROM clause specifies one or more source + tables for the SELECT. If multiple sources are + specified, the result is the Cartesian product (cross join) of all + the sources. But usually qualification conditions + are added to restrict the returned rows to a small subset of the + Cartesian product. - When a FROM item is a simple table name, it implicitly includes rows - from sub-tables (inheritance children) of the table. - ONLY will - suppress rows from sub-tables of the table. Before - PostgreSQL 7.1, - this was the default result, and adding sub-tables was done - by appending * to the table name. - This old behavior is available via the command - SET SQL_Inheritance TO OFF. - + FROM-clause elements can contain: - - A FROM item can also be a parenthesized - sub-SELECT (note that an alias clause is - required for a sub-SELECT!). This is an - extremely useful feature since it's the only way to get multiple - levels of grouping, aggregation, or sorting in a single query. - + + + table_name + + + The name (optionally schema-qualified) of an existing table or + view. If ONLY is specified, only that table is + scanned. If ONLY is not specified, the table and + all its descendant tables (if any) are scanned. * + can be appended to the table name to indicate that descendant + tables are to be scanned, but in the current version, this is + the default behavior. (In releases before 7.1, + ONLY was the default behavior.) The default + behavior can be modified by changing the + sql_interitance configuration option. + + + + + + alias + + + A substitute name for the FROM item containing the + alias. An alias is used for brevity or to eliminate ambiguity + for self-joins (where the same table is scanned multiple + times). When an alias is provided, it completely hides the + actual name of the table or function; for example given + FROM foo AS f, the remainder of the + SELECT must refer to this FROM + item as f not foo. If an alias is + written, a column alias list can also be written to provide + substitute names for one or more columns of the table. + + + + + + select + + + A sub-SELECT can appear in the + FROM clause. This acts as though its + output were created as a temporary table for the duration of + this single SELECT command. Note that the + sub-SELECT must be surrounded by + parentheses, and an alias must be + provided for it. + + + - - A FROM item can be a table function (typically, a function that returns - multiple rows and/or columns, though actually any function can be used). - The function is invoked with the given argument value(s), and then its - output is scanned as though it were a table. - + + function_name + + + Function calls can appear in the FROM + clause. (This is especially useful for functions that return + result sets, but any function can be used.) This acts as + though its output were created as a temporary table for the + duration of this single SELECT command. An + alias may also be used. If an alias is written, a column alias + list can also be written to provide substitute names for one + or more attributes of the function's composite return type. If + the function has been defined as returning the record + data type, then an alias or the key word AS must + be present, followed by a column definition list in the form + ( column_name data_type , ... + ). The column definition list must match the actual + number and types of columns returned by the function. + + + + + + join_type + + + One of + + + [ INNER ] JOIN + + + LEFT [ OUTER ] JOIN + + + RIGHT [ OUTER ] JOIN + + + FULL [ OUTER ] JOIN + + + CROSS JOIN + + - - In some cases it is useful to define table functions that can return - different column sets depending on how they are invoked. To support this, - the table function can be declared as returning the pseudo-type - record. When such a function is used in FROM, it must be - followed by an alias, or the keyword AS alone, - and then by a parenthesized list of column names and types. This provides - a query-time composite type definition. The composite type definition - must match the actual composite type returned from the function, or an - error will be reported at run-time. - + For the INNER and OUTER join types, a + join condition must be specified, namely exactly one of + NATURAL, ON join_condition, or + USING (join_column [, ...]). + See below for the meaning. For CROSS JOIN, + none of these clauses may appear. + - - Finally, a FROM item can be a JOIN clause, which combines two simpler - FROM items. (Use parentheses if necessary to determine the order - of nesting.) - + + A JOIN clause, combines two + FROM items. (Use parentheses if necessary to + determine the order of nesting.) + - - A CROSS JOIN or INNER JOIN is a simple Cartesian product, - the same as you get from listing the two items at the top level of FROM. - CROSS JOIN is equivalent to INNER JOIN ON (TRUE), that is, no rows are - removed by qualification. These join types are just a notational - convenience, since they do nothing you couldn't do with plain FROM and - WHERE. - + + CROSS JOIN and INNER JOIN + produce a simple Cartesian product, the same as you get from + listing the two items at the top level of FROM. + CROSS JOIN is equivalent to INNER JOIN ON + (true), that is, no rows are removed by qualification. + These join types are just a notational convenience, since they + do nothing you couldn't do with plain FROM and + WHERE. + - - LEFT OUTER JOIN returns all rows in the qualified Cartesian product - (i.e., all combined rows that pass its ON condition), plus one copy of each - row in the left-hand table for which there was no right-hand row that - passed the ON condition. This left-hand row is extended to the full - width of the joined table by inserting null values for the right-hand columns. - Note that only the JOIN's own ON or USING condition is considered while - deciding which rows have matches. Outer ON or WHERE conditions are - applied afterwards. - + + LEFT OUTER JOIN returns all rows in the qualified + Cartesian product (i.e., all combined rows that pass its join + condition), plus one copy of each row in the left-hand table + for which there was no right-hand row that passed the join + condition. This left-hand row is extended to the full width + of the joined table by inserting null values for the + right-hand columns. Note that only the JOIN + clauses own condition is considered while deciding which rows + have matches. Outer conditions are applied afterwards. + - - Conversely, RIGHT OUTER JOIN returns all the joined rows, plus one row - for each unmatched right-hand row (extended with nulls on the left). - This is just a notational - convenience, since you could convert it to a LEFT OUTER JOIN by switching - the left and right inputs. - + + Conversely, RIGHT OUTER JOIN returns all the + joined rows, plus one row for each unmatched right-hand row + (extended with nulls on the left). This is just a notational + convenience, since you could convert it to a LEFT + OUTER JOIN by switching the left and right inputs. + - - FULL OUTER JOIN returns all the joined rows, plus one row for each - unmatched left-hand row (extended with nulls on the right), plus one row - for each unmatched right-hand row (extended with nulls on the left). - + + FULL OUTER JOIN returns all the joined rows, plus + one row for each unmatched left-hand row (extended with nulls + on the right), plus one row for each unmatched right-hand row + (extended with nulls on the left). + + + + + + ON join_condition + + + join_condition is + an expression resulting in a value of type + boolean (similar to a WHERE + clause) that specifies which rows in a join are considered to + match. + + + + + + USING (join_column [, ...]) + + + A clause of the form USING ( a, b, ... ) is + shorthand for ON left_table.a = right_table.a AND + left_table.b = right_table.b .... Also, + USING implies that only one of each pair of + equivalent columns will be included in the join output, not + both. + + + - - For all the JOIN types except CROSS JOIN, you must write exactly one of - ON join_condition, - USING ( join_column_list ), - or NATURAL. ON is the most general case: you can write any qualification - expression involving the two tables to be joined. - A USING column list ( a, b, ... ) is shorthand for the ON condition - left_table.a = right_table.a AND left_table.b = right_table.b ... - Also, USING implies that only one of each pair of equivalent columns will - be included in the JOIN output, not both. NATURAL is shorthand for - a USING list that mentions all similarly-named columns in the tables. + + NATURAL + + + NATURAL is shorthand for a + USING list that mentions all columns in the two + tables that have the same names. + + + + - - 2000-03-15 - - - WHERE Clause - + <literal>WHERE</literal> Clause - The optional WHERE condition has the general form: - - -WHERE boolean_expr - - - boolean_expr - can consist of any expression which evaluates to a Boolean value. - In many cases, this expression will be: - - - expr cond_op expr - - - or - - - log_op expr - - - where cond_op - can be one of: =, <, <=, >, >= or <>, - a conditional operator like ALL, ANY, IN, LIKE, or a - locally defined operator, - and log_op can be one - of: AND, OR, NOT. - SELECT will ignore all rows for which the WHERE condition does not return - TRUE. + The optional WHERE clause has the general form + +WHERE condition + + where condition is + any expression that evaluates to a result of type + boolean. Any row that does not satisfy this + condition will be eliminated from the output. A row satisfies the + condition if it returns true when the actual row values are + substituted for any variable references. - - 2000-03-15 - - - GROUP BY Clause - + <literal>GROUP BY</literal> Clause + - GROUP BY specifies a grouped table derived by the application - of this clause: - -GROUP BY expression [, ...] - + The optional GROUP BY clause has the general form + +GROUP BY expression [, ...] + - GROUP BY will condense into a single row all selected rows that - share the same values for the grouped columns. Aggregate - functions, if any, are computed across all rows making up each - group, producing a separate value for each group (whereas without - GROUP BY, an aggregate produces a single value computed across all - the selected rows). When GROUP BY is present, it is not valid for - the SELECT output expression(s) to refer to + GROUP BY will condense into a single row all + selected rows that share the same values for the grouped + expressions. expression can be an input column + name, or the name or ordinal number of an output column + (SELECT list), or it can be an arbitrary + expression formed from input-column values. In case of ambiguity, + a GROUP BY name will be interpreted as an + input-column name rather than an output column name. + + + + Aggregate functions, if any are used, are computed across all rows + making up each group, producing a separate value for each group + (whereas without GROUP BY, an aggregate + produces a single value computed across all the selected rows). + When GROUP BY is present, it is not valid for + the SELECT list expressions to refer to ungrouped columns except within aggregate functions, since there would be more than one possible value to return for an ungrouped column. - - - A GROUP BY item can be an input column name, or the name or - ordinal number of an output column (SELECT - expression), or it can be an arbitrary expression formed from - input-column values. In case of ambiguity, a GROUP BY name will - be interpreted as an input-column name rather than an output - column name. - - - 2000-03-15 - - - HAVING Clause - - - The optional HAVING condition has the general form: - - -HAVING boolean_expr - - - where boolean_expr is the same - as specified for the WHERE clause. - - - - HAVING specifies a grouped table derived by the elimination - of group rows that do not satisfy the - boolean_expr. - HAVING is different from WHERE: - WHERE filters individual rows before application of GROUP BY, - while HAVING filters group rows created by GROUP BY. - + <literal>HAVING</literal> Clause - Each column referenced in - boolean_expr shall unambiguously - reference a grouping column, unless the reference appears within an - aggregate function. + The optional HAVING clause has the general form + +HAVING condition + + where condition is + the same as specified for the WHERE clause. + + + + HAVING eliminates group rows that do not + satisfy the condition. HAVING is different + from WHERE: WHERE filters + individual rows before the application of GROUP + BY, while HAVING filters group rows + created by GROUP BY. Each column referenced in + condition must + unambiguously reference a grouping column, unless the reference + appears within an aggregate function. - - - 2000-03-15 - - - ORDER BY Clause - + + <literal>UNION</literal> Clause + - -ORDER BY expression [ ASC | DESC | USING operator ] [, ...] - - - - An ORDER BY item can be the name or ordinal number of an output - column (SELECT expression), or it can be an - arbitrary expression formed from input-column values. In case of - ambiguity, an ORDER BY name will be interpreted as an - output-column name. - - - The ordinal number refers to the ordinal (left-to-right) position - of the result column. This feature makes it possible to define an ordering - on the basis of a column that does not have a unique name. - This is never absolutely necessary because it is always possible - to assign a name to a result column using the AS clause, e.g.: - -SELECT title, date_prod + 1 AS newlen FROM films ORDER BY newlen; - - - - It is also possible to ORDER BY - arbitrary expressions (an extension to SQL92), - including fields that do not appear in the - SELECT result list. - Thus the following statement is legal: - -SELECT name FROM distributors ORDER BY code; - - A limitation of this feature is that an ORDER BY clause applying to the - result of a UNION, INTERSECT, or EXCEPT query may only specify an output - column name or number, not an expression. + The UNION clause has this general form: + +select_statement UNION [ ALL ] select_statement + + select_statement is + any SELECT statement without an ORDER + BY, LIMIT, or FOR UPDATE clause. + (ORDER BY and LIMIT can be attached to a + subexpression if it is enclosed in parentheses. Without + parentheses, these clauses will be taken to apply to the result of + the UNION, not to its right-hand input + expression.) - Note that if an ORDER BY item is a simple name that matches both - a result column name and an input column name, ORDER BY will interpret - it as the result column name. This is the opposite of the choice that - GROUP BY will make in the same situation. This inconsistency is - mandated by the SQL92 standard. + The UNION operator computes the set union of + the rows returned by the involved SELECT + statements. A row is in the set union of two result sets if it + appears in at least one of the result sets. The two + SELECT statements that represent the direct + operands of the UNION must produce the same + number of columns, and corresponding columns must be of compatible + data types. - Optionally one may add the key word DESC (descending) - or ASC (ascending) after each column name in the - ORDER BY clause. If not specified, ASC is - assumed by default. Alternatively, a specific ordering operator - name may be specified. ASC is equivalent to - USING < and DESC is equivalent to - USING >. + The result of UNION does not contain any duplicate + rows unless the ALL option is specified. + ALL prevents elimination of duplicates. + + + + Multiple UNION operators in the same + SELECT statement are evaluated left to right, + unless otherwise indicated by parentheses. + + + + Currently, FOR UPDATE may not be specified either for + a UNION result or for the inputs of UNION. + + + + + <literal>INTERSECT</literal> Clause + + + The INTERSECT clause has this general form: + +select_statement INTERSECT [ ALL ] select_statement + + select_statement is + any SELECT statement without an ORDER + BY, LIMIT, or FOR UPDATE clause. - The null value sorts higher than any other value in a domain. In other - words, with ascending sort order nulls sort at the end and with - descending sort order nulls sort at the beginning. + The INTERSECT operator computes the set + intersection of the rows returned by the involved + SELECT statements. A row is in the + intersection of two result sets if it appears in both result sets. + + + + The result of INTERSECT does not contain any + duplicate rows unless the ALL option is specified. + With ALL, a row that has m duplicates in the left + table and n duplicates in the right table will appear min(m,n) + times in the result set. + + + + Multiple INTERSECT operators in the same + SELECT statement are evaluated left to right, + unless parentheses dictate otherwise. + INTERSECT binds more tightly than + UNION. That is, A UNION B INTERSECT + C will be read as A UNION (B INTERSECT + C). + + + + + <literal>EXCEPT</literal> Clause + + + The EXCEPT clause has this general form: + +select_statement EXCEPT [ ALL ] select_statement + + select_statement is + any SELECT statement without an ORDER + BY, LIMIT, or FOR UPDATE clause. + + + + The EXCEPT operator computes the set of rows + that are in the result of the left SELECT + statement but not in the result of the right one. + + + + The result of EXCEPT does not contain any + duplicate rows unless the ALL option is specified. + With ALL, a row that has m duplicates in the left + table and n duplicates in the right table will appear max(m-n,0) + times in the result set. + + + + Multiple EXCEPT operators in the same + SELECT statement are evaluated left to right, + unless parentheses dictate otherwise. EXCEPT binds at + the same level as UNION. + + + + + <command>SELECT</command> List + + + The SELECT list (between the key words + SELECT and FROM) specifies expressions + that form the output rows of the SELECT + statement. The expressions can (and usually do) refer to columns + computed in the FROM clause. Using the clause + AS output_name, another + name can be specified for an output column. This name is + primarily used to label the column for display. It can also be + used to refer to the column's value in ORDER BY and + GROUP BY clauses, but not in the WHERE or + HAVING clauses; there you must write out the + expression instead. + + + + Instead of an expression, * can be written in + the output list as a shorthand for all the columns of the selected + rows. Also, one can write table_name.* as a + shorthand for the columns coming from just that table. + + + + + <literal>ORDER BY</literal> Clause + + + The optional ORDER BY clause has this general form: + +ORDER BY expression [ ASC | DESC | USING operator ] [, ...] + + expression can be the + name or ordinal number of an output column + (SELECT list), or it can be an arbitrary + expression formed from input-column values. + + + + The ORDER BY clause causes the result rows to + be sorted according to the specified expressions. If two rows are + equal according to the leftmost expression, the are compared + according to the next expression and so on. If they are equal + according to all specified expressions, they are returned in + random order. + + + + The ordinal number refers to the ordinal (left-to-right) position + of the result column. This feature makes it possible to define an + ordering on the basis of a column that does not have a unique + name. This is never absolutely necessary because it is always + possible to assign a name to a result column using the + AS clause. + + + + It is also possible to use arbitrary expressions in the + ORDER BY clause, including columns that do not + appear in the SELECT result list. Thus the + following statement is valid: + +SELECT name FROM distributors ORDER BY code; + + A limitation of this feature is that an ORDER BY + clause applying to the result of a UNION, + INTERSECT, or EXCEPT clause may only + specify an output column name or number, not an expression. + + + + If an ORDER BY expression is a simple name that + matches both a result column name and an input column name, + ORDER BY will interpret it as the result column name. + This is the opposite of the choice that GROUP BY will + make in the same situation. This inconsistency is made to be + compatible with the SQL standard. + + + + Optionally one may add the key word ASC (ascending) or + DESC (descending) after each expression in the + ORDER BY clause. If not specified, ASC is + assumed by default. Alternatively, a specific ordering operator + name may be specified in the USING clause. + ASC is equivalent to USING < and + DESC is equivalent to USING >. + + + + The null value sorts higher than any other value. In other words, + with ascending sort order, null values sort at the end, and with + descending sort order, null values sort at the beginning. @@ -676,273 +675,147 @@ SELECT name FROM distributors ORDER BY code; collation order that was established when the database cluster was initialized. - - - - 2000-12-11 - - - UNION Clause - - - -table_query UNION [ ALL ] table_query - [ ORDER BY expression [ ASC | DESC | USING operator ] [, ...] ] - [ LIMIT { count | ALL } ] - [ OFFSET start ] - - - where - table_query - specifies any select expression without an ORDER BY, LIMIT, or FOR UPDATE - clause. (ORDER BY and LIMIT can be attached to a sub-expression - if it is enclosed in parentheses. Without parentheses, these clauses - will be taken to apply to the result of the UNION, not to its right-hand - input expression.) - - - - The UNION operator computes the collection (set union) of the rows - returned by the queries involved. The two - SELECT statements that represent the direct - operands of the UNION must produce the same number of columns, and - corresponding columns must be of compatible data types. - - - - The result of UNION does not contain any duplicate rows - unless the ALL option is specified. ALL prevents elimination of - duplicates. - - - - Multiple UNION operators in the same SELECT - statement are evaluated left to right, unless otherwise indicated - by parentheses. - - - - Currently, FOR UPDATE may not be specified either for a UNION result - or for the inputs of a UNION. - - - - - - - 2000-12-11 - - - INTERSECT Clause - - - -table_query INTERSECT [ ALL ] table_query - [ ORDER BY expression [ ASC | DESC | USING operator ] [, ...] ] - [ LIMIT { count | ALL } ] - [ OFFSET start ] - - - where - table_query - specifies any select expression without an ORDER BY, LIMIT, or - FOR UPDATE clause. - - - - INTERSECT is similar to UNION, except that it produces only rows that - appear in both query outputs, rather than rows that appear in either. - - - - The result of INTERSECT does not contain any duplicate rows - unless the ALL option is specified. With ALL, a row that has - m duplicates in L and n duplicates in R will appear min(m,n) times. - - - - Multiple INTERSECT operators in the same SELECT statement are - evaluated left to right, unless parentheses dictate otherwise. - INTERSECT binds more tightly than UNION --- that is, - A UNION B INTERSECT C will be read as - A UNION (B INTERSECT C) unless otherwise specified by parentheses. - - - - - - 2000-12-11 - - - EXCEPT Clause - - - -table_query EXCEPT [ ALL ] table_query - [ ORDER BY expression [ ASC | DESC | USING operator ] [, ...] ] - [ LIMIT { count | ALL } ] - [ OFFSET start ] - - - where - table_query - specifies any select expression without an ORDER BY, LIMIT, - or FOR UPDATE clause. - - - - EXCEPT is similar to UNION, except that it produces only rows that - appear in the left query's output but not in the right query's output. - - - - The result of EXCEPT does not contain any duplicate rows - unless the ALL option is specified. With ALL, a row that has - m duplicates in L and n duplicates in R will appear max(m-n,0) times. - - - - Multiple EXCEPT operators in the same SELECT statement are - evaluated left to right, unless parentheses dictate otherwise. - EXCEPT binds at the same level as UNION. - - - - - 2000-02-20 - - - LIMIT Clause - + <literal>LIMIT</literal> Clause + - - LIMIT { count | ALL } - OFFSET start - - - where - count specifies the - maximum number of rows to return, and - start specifies the - number of rows to skip before starting to return rows. + The LIMIT clause consists of two independent + clauses: + +LIMIT { count | ALL } +OFFSET start + + count specifies the + maximum number of rows to return, and start specifies the number of rows + to skip before starting to return rows. - LIMIT allows you to retrieve just a portion of the rows that are generated - by the rest of the query. If a limit count is given, no more than that - many rows will be returned. If an offset is given, that many rows will - be skipped before starting to return rows. + When using LIMIT, it is a good idea to use an + ORDER BY clause that constrains the result rows into a + unique order. Otherwise you will get an unpredictable subset of + the query's rows---you may be asking for the tenth through + twentieth rows, but tenth through twentieth in what ordering? You + don't know what ordering unless you specify ORDER BY. - When using LIMIT, it is a good idea to use an ORDER BY clause that - constrains the result rows into a unique order. Otherwise you will get - an unpredictable subset of the query's rows---you may be asking for - the tenth through twentieth rows, but tenth through twentieth in what - ordering? You don't know what ordering unless you specify ORDER BY. + The query planner takes LIMIT into account when + generating a query plan, so you are very likely to get different + plans (yielding different row orders) depending on what you use + for LIMIT and OFFSET. Thus, using + different LIMIT/OFFSET values to select + different subsets of a query result will give + inconsistent results unless you enforce a predictable + result ordering with ORDER BY. This is not a bug; it + is an inherent consequence of the fact that SQL does not promise + to deliver the results of a query in any particular order unless + ORDER BY is used to constrain the order. + + + + + <literal>DISTINCT</literal> Clause + + + If DISTINCT is specified, all duplicate rows are + removed from the result set (one row is kept from each group of + duplicates). ALL specifies the opposite: all rows are + kept; that is the default. - As of PostgreSQL 7.0, the - query optimizer takes LIMIT into account when generating a query plan, - so you are very likely to get different plans (yielding different row - orders) depending on what you use for LIMIT and OFFSET. Thus, using - different LIMIT/OFFSET values to select different subsets of a query - result will give inconsistent results unless - you enforce a predictable result ordering with ORDER BY. This is not - a bug; it is an inherent consequence of the fact that SQL does not - promise to deliver the results of a query in any particular order - unless ORDER BY is used to constrain the order. + DISTINCT ON ( expression [, ...] ) + keeps only the first row of each set of rows where the given + expressions evaluate to equal. The DISTINCT ON + expressions are interpreted using the same rules as for + ORDER BY (see above). Note that the first + row of each set is unpredictable unless ORDER + BY is used to ensure that the desired row appears first. For + example, + +SELECT DISTINCT ON (location) location, time, report + FROM weather_reports + ORDER BY location, time DESC; + + retrieves the most recent weather report for each location. But + if we had not used ORDER BY to force descending order + of time values for each location, we'd have gotten a report from + an unpredictable time for each location. - - 2002-08-28 - - - FOR UPDATE Clause - + <literal>FOR UPDATE</literal> Clause + - - FOR UPDATE [ OF tablename [, ...] ] - + The FOR UPDATE clause has this form: + +FOR UPDATE [ OF table_name [, ...] ] + - FOR UPDATE causes the rows retrieved by the query to be locked as - though for update. This prevents them from being modified or - deleted by other transactions until the current transaction ends; - that is, other transactions that attempt - UPDATE, DELETE, or - SELECT FOR UPDATE of these rows will be blocked - until the current transaction ends. Also, if an - UPDATE, DELETE, or - SELECT FOR UPDATE from another transaction has - already locked a selected row or rows, SELECT FOR + FOR UPDATE causes the rows retrieved by the + SELECT statement to be locked as though for + update. This prevents them from being modified or deleted by + other transactions until the current transaction ends. That is, + other transactions that attempt UPDATE, + DELETE, or SELECT FOR UPDATE + of these rows will be blocked until the current transaction ends. + Also, if an UPDATE, DELETE, + or SELECT FOR UPDATE from another transaction + has already locked a selected row or rows, SELECT FOR UPDATE will wait for the other transaction to complete, and will then lock and return the updated row (or no row, if the - row was deleted). For further discussion see . + row was deleted). For further discussion see . - If specific tables are named in FOR UPDATE, then only rows coming - from those tables are locked; any other tables used in the - SELECT are simply read as usual. + If specific tables are named in FOR UPDATE, + then only rows coming from those tables are locked; any other + tables used in the SELECT are simply read as + usual. - FOR UPDATE cannot be used in contexts where returned rows can't be clearly - identified with individual table rows; for example it can't be used with - aggregation. + FOR UPDATE cannot be used in contexts where + returned rows can't be clearly identified with individual table + rows; for example it can't be used with aggregation. - FOR UPDATE may appear before LIMIT for compatibility with - pre-7.3 applications. However, it effectively executes after LIMIT, - and so that is the recommended place to write it. + FOR UPDATE may appear before + LIMIT for compatibility with PostgreSQL + versions before 7.3. It effectively executes after + LIMIT, however, and so that is the recommended + place to write it. - - - - Usage - + + Examples To join the table films with the table distributors: - + SELECT f.title, f.did, d.name, f.date_prod, f.kind FROM distributors d, films f WHERE f.did = d.did - title | did | name | date_prod | kind ----------------------------+-----+------------------+------------+---------- - The Third Man | 101 | British Lion | 1949-12-23 | Drama - The African Queen | 101 | British Lion | 1951-08-11 | Romantic - Une Femme est une Femme | 102 | Jean Luc Godard | 1961-03-12 | Romantic - Vertigo | 103 | Paramount | 1958-11-14 | Action - Becket | 103 | Paramount | 1964-02-03 | Drama - 48 Hrs | 103 | Paramount | 1982-10-22 | Action - War and Peace | 104 | Mosfilm | 1967-02-12 | Drama - West Side Story | 105 | United Artists | 1961-01-03 | Musical - Bananas | 105 | United Artists | 1971-07-13 | Comedy - Yojimbo | 106 | Toho | 1961-06-16 | Drama - There's a Girl in my Soup | 107 | Columbia | 1970-06-11 | Comedy - Taxi Driver | 107 | Columbia | 1975-05-15 | Action - Absence of Malice | 107 | Columbia | 1981-11-15 | Action - Storia di una donna | 108 | Westward | 1970-08-15 | Romantic - The King and I | 109 | 20th Century Fox | 1956-08-11 | Musical - Das Boot | 110 | Bavaria Atelier | 1981-11-11 | Drama - Bed Knobs and Broomsticks | 111 | Walt Disney | | Musical -(17 rows) + title | did | name | date_prod | kind +-------------------+-----+--------------+------------+---------- + The Third Man | 101 | British Lion | 1949-12-23 | Drama + The African Queen | 101 | British Lion | 1951-08-11 | Romantic + ... @@ -951,7 +824,7 @@ SELECT f.title, f.did, d.name, f.date_prod, f.kind the results by kind: -SELECT kind, SUM(len) AS total FROM films GROUP BY kind; +SELECT kind, sum(len) AS total FROM films GROUP BY kind; kind | total ----------+------- @@ -960,7 +833,6 @@ SELECT kind, SUM(len) AS total FROM films GROUP BY kind; Drama | 14:28 Musical | 06:42 Romantic | 04:38 -(5 rows) @@ -970,16 +842,15 @@ SELECT kind, SUM(len) AS total FROM films GROUP BY kind; that are less than 5 hours: -SELECT kind, SUM(len) AS total +SELECT kind, sum(len) AS total FROM films GROUP BY kind - HAVING SUM(len) < INTERVAL '5 hour'; + HAVING sum(len) < interval '5 hours'; - kind | total + kind | total ----------+------- Comedy | 02:58 Romantic | 04:38 -(2 rows) @@ -988,7 +859,7 @@ SELECT kind, SUM(len) AS total results according to the contents of the second column (name): - + SELECT * FROM distributors ORDER BY name; SELECT * FROM distributors ORDER BY 2; @@ -1007,7 +878,6 @@ SELECT * FROM distributors ORDER BY 2; 111 | Walt Disney 112 | Warner Bros. 108 | Westward -(13 rows) @@ -1016,7 +886,7 @@ SELECT * FROM distributors ORDER BY 2; distributors and actors, restricting the results to those that begin with letter W in each table. Only distinct rows are wanted, so the - ALL keyword is omitted: + key word ALL is omitted. distributors: actors: @@ -1028,12 +898,12 @@ distributors: actors: ... ... SELECT distributors.name - FROM distributors - WHERE distributors.name LIKE 'W%' + FROM distributors + WHERE distributors.name LIKE 'W%' UNION SELECT actors.name - FROM actors - WHERE actors.name LIKE 'W%'; + FROM actors + WHERE actors.name LIKE 'W%'; name ---------------- @@ -1047,173 +917,135 @@ SELECT actors.name - This example shows how to use a table function, both with and without - a column definition list. + This example shows how to use a function in the FROM + clause, both with and without a column definition list. -distributors: - did | name ------+-------------- - 108 | Westward - 111 | Walt Disney - 112 | Warner Bros. - ... - -CREATE FUNCTION distributors(int) - RETURNS SETOF distributors AS ' - SELECT * FROM distributors WHERE did = $1; - ' LANGUAGE SQL; +CREATE FUNCTION distributors(int) RETURNS SETOF distributors AS ' + SELECT * FROM distributors WHERE did = $1; +' LANGUAGE SQL; SELECT * FROM distributors(111); did | name -----+------------- 111 | Walt Disney -(1 row) -CREATE FUNCTION distributors_2(int) - RETURNS SETOF RECORD AS ' - SELECT * FROM distributors WHERE did = $1; - ' LANGUAGE SQL; +CREATE FUNCTION distributors_2(int) RETURNS SETOF record AS ' + SELECT * FROM distributors WHERE did = $1; +' LANGUAGE SQL; SELECT * FROM distributors_2(111) AS (f1 int, f2 text); f1 | f2 -----+------------- 111 | Walt Disney -(1 row) - - - Compatibility - + + Compatibility + + + Of course, the SELECT statement is compatible + with the SQL standard. But there are some extensions and some + missing features. + - - - 1998-09-24 - - Extensions + + Omitted <literal>FROM</literal> Clauses -PostgreSQL allows one to omit -the FROM clause from a query. This feature -was retained from the original PostQUEL query language. It has -a straightforward use to compute the results of simple expressions: - - + PostgreSQL allows one to omit the + FROM clause. It has a straightforward use to + compute the results of simple expressions: + SELECT 2+2; ?column? ---------- 4 - - -Some other SQL databases cannot do this except by -introducing a dummy one-row table to do the select from. A less -obvious use is to abbreviate a normal select from one or more tables: - - -SELECT distributors.* WHERE distributors.name = 'Westward'; - - did | name ------+---------- - 108 | Westward - - -This works because an implicit FROM item is added for each table that is -referenced in the query but not mentioned in FROM. While this is a convenient -shorthand, it's easy to misuse. For example, the query - -SELECT distributors.* FROM distributors d; - -is probably a mistake; most likely the user meant - -SELECT d.* FROM distributors d; - -rather than the unconstrained join - -SELECT distributors.* FROM distributors d, distributors distributors; - -that he will actually get. To help detect this sort of mistake, -PostgreSQL 7.1 -and later will warn if the implicit-FROM feature is used in a query that also -contains an explicit FROM clause. - + + Some other SQL databases cannot do this except + by introducing a dummy one-row table from which to do the + SELECT. - The table-function feature is a PostgreSQL - extension. + A less obvious use is to abbreviate a normal + SELECT from tables: + +SELECT distributors.* WHERE distributors.name = 'Westward'; + + did | name +-----+---------- + 108 | Westward + + This works because an implicit FROM item is + added for each table that is referenced in other parts of the + SELECT statement but not mentioned in + FROM. + + + + While this is a convenient shorthand, it's easy to misuse. For + example, the command + +SELECT distributors.* FROM distributors d; + + is probably a mistake; most likely the user meant + +SELECT d.* FROM distributors d; + + rather than the unconstrained join + +SELECT distributors.* FROM distributors d, distributors distributors; + + that he will actually get. To help detect this sort of mistake, + PostgreSQL will warn if the implicit-FROM + feature is used in a SELECT statement that also + contains an explicit FROM clause. - - - 1998-09-24 - - - <acronym>SQL92</acronym> - + + The <literal>AS</literal> Key Word + + In the SQL standard, the optional key word AS is just + noise and can be omitted without affecting the meaning. The + PostgreSQL parser requires this key + word when renaming output columns because the type extensibility + features lead to parsing ambiguities in this context. + AS is optional in FROM + items, however. - - - - 1998-04-15 - - - SELECT Clause - - - In the SQL92 standard, the optional keyword AS - is just noise and can be - omitted without affecting the meaning. - The PostgreSQL parser requires this keyword when - renaming output columns because the type extensibility features lead to - parsing ambiguities - in this context. AS is optional in FROM items, however. - - - The DISTINCT ON phrase is not part of SQL92. - Nor are LIMIT and OFFSET. - - - - In SQL92, an ORDER BY clause may only use result - column names or numbers, while a GROUP BY clause may only use input - column names. - PostgreSQL extends each of these clauses to - allow the other choice as well (but it uses the standard's interpretation - if there is ambiguity). - PostgreSQL also allows both clauses to specify - arbitrary expressions. Note that names appearing in an expression will - always be taken as input-column names, not as result-column names. - - + - - - 1998-09-24 - - - UNION/INTERSECT/EXCEPT Clause - - - The SQL92 syntax for UNION/INTERSECT/EXCEPT allows an - additional CORRESPONDING BY option: - -table_query UNION [ALL] - [CORRESPONDING [BY (column [,...])]] - table_query - + + Namespace Available to <literal>GROUP BY</literal> and <literal>ORDER BY</literal> - - The CORRESPONDING BY clause is not supported by - PostgreSQL. - - - + + In the SQL standard, an ORDER BY clause may + only use result column names or numbers, while a GROUP + BY clause may only use expressions based on input column + names. PostgreSQL extends each of + these clauses to allow the other choice as well (but it uses the + standard's interpretation if there is ambiguity). + PostgreSQL also allows both clauses to + specify arbitrary expressions. Note that names appearing in an + expression will always be taken as input-column names, not as + result-column names. + + + + + Nonstandard Clauses + + + The clauses DISTINCT ON, + LIMIT, and OFFSET are not + defined in the SQL standard. + diff --git a/doc/src/sgml/ref/select_into.sgml b/doc/src/sgml/ref/select_into.sgml index c14911638b..131bb6e1a2 100644 --- a/doc/src/sgml/ref/select_into.sgml +++ b/doc/src/sgml/ref/select_into.sgml @@ -1,5 +1,5 @@ @@ -8,18 +8,14 @@ PostgreSQL documentation SELECT INTO SQL - Language Statements + - - SELECT INTO - - - create a new table from the results of a query - + SELECT INTO + create a new table from the results of a query + + - - 2000-12-11 - - + SELECT [ ALL | DISTINCT [ ON ( expression [, ...] ) ] ] * | expression [ AS output_name ] [, ...] INTO [ TEMPORARY | TEMP ] [ TABLE ] new_table @@ -32,71 +28,11 @@ SELECT [ ALL | DISTINCT [ ON ( expressioncount | ALL } ] [ OFFSET start ] [ FOR UPDATE [ OF tablename [, ...] ] ] - - - - - 2001-03-20 - - - Inputs - - - - - - TEMPORARY - TEMP - - - If specified, the table is created as a temporary table. - Refer to for details. - - - - - - new_table - - - The name (optionally schema-qualified) of the table to be created. - - - - - - - - All other inputs are described in detail for - . - - - - - - 2001-03-20 - - - Outputs - - - - Refer to - - and - - for a summary of possible output messages. - - + - - - 2001-03-20 - - - Description - + + Description SELECT INTO creates a new table and fills it @@ -104,35 +40,81 @@ SELECT [ ALL | DISTINCT [ ON ( expressionSELECT. The new table's columns have the names and data types associated with the output columns of the SELECT. + + + + + Parameters - + + + TEMPORARY or TEMP + - - is functionally equivalent to SELECT INTO. - CREATE TABLE AS is the recommended syntax, since - SELECT INTO is not standard. In fact, this form of - SELECT INTO is not available in PL/pgSQL or , - because they interpret the INTO clause differently. + If specified, the table is created as a temporary table. Refer + to for details. - + + + + + new_table + + + The name (optionally schema-qualified) of the table to be created. + + + + + + + All other parameters are described in detail under . - - - Compatibility - + + Diagnostics - - SQL92 uses SELECT ... INTO to represent selecting - values into scalar variables of a host program, rather than creating - a new table. This indeed is the usage found in PL/pgSQL and . - The PostgreSQL usage of SELECT - INTO to represent table creation is historical. It's best - to use CREATE TABLE AS for this purpose in new code. - (CREATE TABLE AS isn't standard either, but it's - less likely to cause confusion.) - + + Refer to + + and + + for a summary of possible output messages. + + + + + Notes + + + + is functionally equivalent to SELECT INTO. + CREATE TABLE AS is the recommended syntax, since + this form of SELECT INTO is not available in + ECPG or + PL/pgSQL, because they interpret the + INTO clause differently. + + + + + Compatibility + + + The SQL standard uses SELECT ... INTO to + represent selecting values into scalar variables of a host program, + rather than creating a new table. This indeed is the usage found + in ECPG (see ) and + PL/pgSQL (see ). + The PostgreSQL usage of SELECT + INTO to represent table creation is historical. It's + best to use CREATE TABLE AS for this purpose in + new code. (CREATE TABLE AS isn't standard + either, but it's less likely to cause confusion.) + diff --git a/doc/src/sgml/ref/set.sgml b/doc/src/sgml/ref/set.sgml index 75dc366c3f..eba67d0577 100644 --- a/doc/src/sgml/ref/set.sgml +++ b/doc/src/sgml/ref/set.sgml @@ -1,5 +1,5 @@ @@ -8,73 +8,20 @@ PostgreSQL documentation SET SQL - Language Statements + SET change a run-time parameter + - + SET [ SESSION | LOCAL ] variable { TO | = } { value | 'value' | DEFAULT } SET [ SESSION | LOCAL ] TIME ZONE { timezone | LOCAL | DEFAULT } - - - - Inputs - - - - - - - - Specifies that the command takes effect for the current session. - (This is the default if neither - - - - - - - - Specifies that the command takes effect for only the current - transaction. After COMMIT or ROLLBACK, - the session-level setting takes effect again. Note that - SET LOCAL will appear to have no effect if it's - executed outside a BEGIN block, since the transaction - will end immediately. - - - - - - variable - - - Name of a settable run-time parameter. - - - - - - value - - - New value of parameter. can be - used to specify resetting the parameter to its default - value. Lists of strings are allowed, but more complex - constructs may need to be single or double quoted. - - - - - - - + - + Description @@ -83,7 +30,7 @@ SET [ SESSION | LOCAL ] TIME ZONE { timezone can be changed on-the-fly with SET. (But some require superuser privileges to change, and others cannot - be changed after server or session start.) Note that + be changed after server or session start.) SET only affects the value used by the current session. @@ -114,236 +61,153 @@ SET [ SESSION | LOCAL ] TIME ZONE { timezoneautocommit section in for details. + + + + Parameters + + + + SESSION + + + Specifies that the command takes effect for the current session. + (This is the default if neither SESSION nor + LOCAL appears.) + + + + + + LOCAL + + + Specifies that the command takes effect for only the current + transaction. After COMMIT or ROLLBACK, + the session-level setting takes effect again. Note that + SET LOCAL will appear to have no effect if it is + executed outside a BEGIN block, since the + transaction will end immediately. + + + + + + variable + + + Name of a settable run-time parameter. Available parameters are + documented in and below. + + + + + + value + + + New value of parameter. Values can be specified as string + constants, identifiers, numbers, or comma-separated lists of + these. DEFAULT can be used to specify + resetting the parameter to its default value. + + + + - Here are additional details about a few of the parameters that can be set: + Besides the configuration parameters documented in , there are a few that can only be + adjusted using the SET command or that have a + special syntax: - DATESTYLE + NAMES - Choose the date/time representation style. Two separate - settings are involved: the default date/time output format and the - interpretation of ambiguous input. + >SET NAMES value is an alias for + SET client_encoding TO value. - - - The following are date/time output styles: - - - - ISO - - - Use ISO 8601-style dates and times (YYYY-MM-DD - HH:MM:SS). This is the default. - - - - - - SQL - - - Use Oracle/Ingres-style dates and times. Note that this - style has nothing to do with SQL (which mandates ISO 8601 - style); the naming of this option is a historical accident. - - - - - - PostgreSQL - - - Use traditional PostgreSQL format. - - - - - - German - - - Use dd.mm.yyyy for numeric date representations. - - - - - - - - The following two options determine both a substyle of the - SQL and PostgreSQL output formats - and the preferred interpretation of ambiguous date input. - - - - European - - - Use dd/mm/yyyy for numeric date representations. - - - - - - NonEuropean - US - - - Use mm/dd/yyyy for numeric date representations. - - - - - - - - A value for SET DATESTYLE can be one from - the first list (output styles), or one from the second list - (substyles), or one from each separated by a comma. - - - - SET DATESTYLE affects interpretation of - input and provides several standard output formats. For - applications needing different variations or tighter control - over input or output, consider using - the to_char family of - functions. - - - - There are several now-deprecated means for setting the date style - in addition to the normal methods of setting it via SET or - a configuration-file entry: - - - Setting the postmaster's PGDATESTYLE environment - variable. (This will be overridden by any of the other methods.) - - - Running postmaster using the option to - set dates to the European convention. - (This overrides environment variables and configuration-file - entries.) - - - Setting the client's PGDATESTYLE environment variable. - If PGDATESTYLE is set in the frontend environment of a client - based on libpq, libpq will automatically set DATESTYLE to the - value of PGDATESTYLE during connection start-up. This is - equivalent to a manually issued SET DATESTYLE. - - - - - NAMES + SEED - SET NAMES is an alias for SET CLIENT_ENCODING. - - - - - - SEED - - - Sets the internal seed for the random number generator. - - - - value - - - The value for the seed to be used by the - random function. Allowed - values are floating-point numbers between 0 and 1, which - are then multiplied by 231-1. - - - - + Sets the internal seed for the random number generator (the + function random). Allowed values are + floating-point numbers between 0 and 1, which are then + multiplied by 231-1. - The seed can also be set by invoking the - setseed SQL function: - - + The seed can also be set by invoking the function + setseed: + SELECT setseed(value); - + - TIME ZONE - TIMEZONE + TIME ZONE - Sets the default time zone for your session. Arguments can be - an SQL time interval constant, an integer or double precision - constant, or a string representing a time zone name recognized - by the host operating system. - - - - Here are some typical values for time zone settings: + >SET TIME ZONE value is an alias + for SET timezone TO value. The + syntax >SET TIME ZONE allows special syntax + for the time zone specification. Here are examples of valid + values: - 'PST8PDT' + 'PST8PDT' - Set the time zone for Berkeley, California. + The time zone for Berkeley, California. - 'Portugal' + 'Portugal' - Set the time zone for Portugal. + The time zone for Portugal. - 'Europe/Rome' + 'Europe/Rome' - Set the time zone for Italy. + The time zone for Italy. - 7 + 7 - Set the time zone to 7 hours offset west from GMT (equivalent + The time zone to 7 hours offset west from UTC (equivalent to PDT). - INTERVAL '08:00' HOUR TO MINUTE + INTERVAL '08:00' HOUR TO MINUTE - Set the time zone to 8 hours offset west from GMT (equivalent + The time zone to 8 hours offset west from UTC (equivalent to PST). - LOCAL - DEFAULT + LOCAL + DEFAULT Set the time zone to your local time zone (the one that @@ -352,43 +216,19 @@ SELECT setseed(value); - - - The available time zone names depend on your operating - system. For example, on Linux - /usr/share/zoneinfo contains the database - of time zones; the names of the files in that directory can be - used as parameters to this command. - - - - If an invalid time zone is specified, the time zone - becomes GMT (on most systems anyway). - - - - If the PGTZ environment variable is set in the frontend - environment of a client based on libpq, libpq will automatically - SET TIMEZONE to the value of - PGTZ during connection start-up. + See for more information + about time zones. - - - Use to show the - current setting of a parameter. - - Diagnostics - - + SET @@ -400,8 +240,7 @@ SELECT setseed(value); - ERROR: 'name' is not a - valid option name + ERROR: 'name' is not a valid option name The parameter you tried to set does not exist. @@ -410,8 +249,7 @@ SELECT setseed(value); - ERROR: 'name': - permission denied + ERROR: 'name': permission denied You must be a superuser to alter certain settings. @@ -420,17 +258,14 @@ SELECT setseed(value); - ERROR: 'name' cannot - be changed after server start + ERROR: 'name' cannot be changed after server start Some parameters are fixed once the server is started. - - @@ -438,81 +273,61 @@ SELECT setseed(value); The function set_config provides equivalent - capability. See . + functionality. See . Examples + + + Set the schema search path: + +SET search_path TO my_schema, public; + + + Set the style of date to traditional - PostgreSQL with European conventions: - -SET DATESTYLE TO PostgreSQL,European; - + POSTGRES with European conventions: + +SET datestyle TO postgres,european; + Set the time zone for Berkeley, California, using quotes to - preserve the uppercase spelling of the time zone name (note - that the date style is PostgreSQL for this - example): - - + preserve the uppercase spelling of the time zone name: + SET TIME ZONE 'PST8PDT'; -SELECT CURRENT_TIMESTAMP AS today; - today ------------------------------------- - Tue Feb 26 07:32:21.42834 2002 PST - - +SELECT current_timestamp AS today; - - Set the time zone for Italy (note the required single quotes to handle - the special characters): - - -SET TIME ZONE 'Europe/Rome'; -SELECT CURRENT_TIMESTAMP AS today; - - today + today ------------------------------- - 2002-10-08 05:39:35.008271+02 - + 2003-04-29 15:02:01.218622-07 + - + Compatibility - - - SQL92 - - - - SET TIME ZONE - extends syntax defined in - SQL9x. SQL9x allows - only numeric time zone offsets while - PostgreSQL allows full time zone - specifier strings as well. All other SET - features are - PostgreSQL extensions. - - + + SET TIME ZONE extends syntax defined in the SQL + standard. The standard allows only numeric time zone offsets while + PostgreSQL allows more flexible + time-zone specifications. All other SET + features are PostgreSQL extensions. + See Also - - , - , - , - , - - + + + + diff --git a/doc/src/sgml/ref/set_constraints.sgml b/doc/src/sgml/ref/set_constraints.sgml index 32abdee89f..3d5b58bee2 100644 --- a/doc/src/sgml/ref/set_constraints.sgml +++ b/doc/src/sgml/ref/set_constraints.sgml @@ -1,20 +1,19 @@ - + SET CONSTRAINTS SQL - Language Statements + SET CONSTRAINTS set the constraint mode of the current transaction + - - 2000-06-01 - - + SET CONSTRAINTS { ALL | constraint [, ...] } { DEFERRED | IMMEDIATE } - + @@ -22,39 +21,26 @@ SET CONSTRAINTS { ALL | constraint SET CONSTRAINTS sets the behavior of constraint - evaluation in the current transaction. In mode, constraints are checked at the end of each - statement. In mode, constraints are not - checked until transaction commit. + evaluation in the current transaction. In + IMMEDIATE mode, constraints are checked at the + end of each statement. In DEFERRED mode, + constraints are not checked until transaction commit. - - - This command only alters the behavior of constraints within the - current transaction. Thus, if you execute this command outside - of an explicit transaction block (such as one started with - BEGIN), it will not appear to have any effect. - If you wish to change the behavior of a constraint without needing - to issue a SET CONSTRAINTS command in every - transaction, specify or - when you create the constraint. - - - - When you change the mode of a constraint to be , the new constraint mode takes effect retroactively: - any outstanding data modifications that would have been checked - at the end of the transaction (when using - ) are instead checked during the + When you change the mode of a constraint to be + IMMEDIATE, the new constraint mode takes effect + retroactively: any outstanding data modifications that would have + been checked at the end of the transaction (when using + DEFERRED) are instead checked during the execution of the SET CONSTRAINTS command. Upon creation, a constraint is always give one of three - characteristics: , - , or - . The third + characteristics: INITIALLY DEFERRED, + INITIALLY IMMEDIATE DEFERRABLE, or + INITIALLY IMMEDIATE NOT DEFERRABLE. The third class is not affected by the SET CONSTRAINTS command. @@ -66,21 +52,30 @@ SET CONSTRAINTS { ALL | constraint - + + Notes + + + This command only alters the behavior of constraints within the + current transaction. Thus, if you execute this command outside of a + transaction block + (BEGIN/COMMIT pair), it will + not appear to have any effect. If you wish to change the behavior + of a constraint without needing to issue a SET + CONSTRAINTS command in every transaction, specify + INITIALLY DEFERRED or INITIALLY + IMMEDIATE when you create the constraint. + + + + Compatibility - - SQL92, SQL99 - - - SET CONSTRAINTS is defined in - SQL92 and SQL99. The - implementation in PostgreSQL complies - with the behavior defined in the standard, except for the - PostgreSQL limitation that SET - CONSTRAINTS cannot be applied to check or unique constraints. - - + + This command complies with the behavior defined in the SQL + standard, except for the limitation that, in PostgreSQL, it only + applies to foreign-key constraints. + diff --git a/doc/src/sgml/ref/set_session_auth.sgml b/doc/src/sgml/ref/set_session_auth.sgml index 88d5578498..f8c0297ada 100644 --- a/doc/src/sgml/ref/set_session_auth.sgml +++ b/doc/src/sgml/ref/set_session_auth.sgml @@ -1,9 +1,5 @@ - + - - 2001-04-21 - - SET SESSION AUTHORIZATION SQL - Language Statements @@ -16,7 +12,7 @@ -SET [ SESSION | LOCAL ] SESSION AUTHORIZATION username +SET [ SESSION | LOCAL ] SESSION AUTHORIZATION username SET [ SESSION | LOCAL ] SESSION AUTHORIZATION DEFAULT RESET SESSION AUTHORIZATION @@ -28,11 +24,10 @@ RESET SESSION AUTHORIZATION This command sets the session user identifier and the current user identifier of the current SQL-session context to be username. The user name may be - written as either an identifier or a string literal. The session - user identifier is valid for the duration of a connection; for - example, it is possible to temporarily become an unprivileged user - and later switch back to become a superuser. + class="parameter">username. The user name may be + written as either an identifier or a string literal. Using this + command, it is possible, for example, to temporarily become an + unprivileged user and later switch back to become a superuser. @@ -52,7 +47,7 @@ RESET SESSION AUTHORIZATION - The @@ -60,9 +55,8 @@ RESET SESSION AUTHORIZATION The DEFAULT and RESET forms reset the session and current user identifiers to be the originally authenticated user - name. These forms are always accepted. + name. These forms may be executed by any user. - @@ -88,18 +82,16 @@ SELECT SESSION_USER, CURRENT_USER; Compatibility - SQL99 - - SQL99 allows some other expressions to appear in place of the - literal username which are not important in - practice. PostgreSQL allows identifier - syntax ("username"), which SQL does not. SQL - does not allow this command during a transaction; - PostgreSQL does not make - this restriction because there is no reason to. The - privileges necessary to execute this command are left - implementation-defined by the standard. + The SQL standard allows some other expressions to appear in place + of the literal username which are not + important in practice. PostgreSQL + allows identifier syntax ("username"), which SQL + does not. SQL does not allow this command during a transaction; + PostgreSQL does not make this + restriction because there is no reason to. The privileges + necessary to execute this command are left implementation-defined + by the standard. diff --git a/doc/src/sgml/ref/set_transaction.sgml b/doc/src/sgml/ref/set_transaction.sgml index f43802d2e0..2ff29bc3d5 100644 --- a/doc/src/sgml/ref/set_transaction.sgml +++ b/doc/src/sgml/ref/set_transaction.sgml @@ -1,9 +1,5 @@ - + - - 2000-11-24 - - SET TRANSACTION SQL - Language Statements @@ -15,12 +11,12 @@ - + SET TRANSACTION [ ISOLATION LEVEL { READ COMMITTED | SERIALIZABLE } ] [ READ WRITE | READ ONLY ] SET SESSION CHARACTERISTICS AS TRANSACTION [ ISOLATION LEVEL { READ COMMITTED | SERIALIZABLE } ] [ READ WRITE | READ ONLY ] - + @@ -28,8 +24,8 @@ SET SESSION CHARACTERISTICS AS TRANSACTION The SET TRANSACTION command sets the transaction - characteristics of the current SQL-transaction. It has no effect on - any subsequent transactions. SET SESSION + characteristics of the current transaction. It has no effect on any + subsequent transactions. SET SESSION CHARACTERISTICS sets the default transaction characteristics for each transaction of a session. SET TRANSACTION can override it for an individual @@ -80,7 +76,9 @@ SET SESSION CHARACTERISTICS AS TRANSACTION or data-modification statement (SELECT, INSERT, DELETE, UPDATE, FETCH, - COPY) of a transaction has been executed. + COPY) of a transaction has been executed. See + for more information about transaction + isolation and concurrency control. @@ -117,25 +115,23 @@ SET default_transaction_isolation = 'value' Compatibility - - SQL92, SQL99 + + Both commands are defined in the SQL standard. + SERIALIZABLE is the default transaction + isolation level in SQL; in PostgreSQL it is + READ COMMITED, but you can change it as + described above. PostgreSQL does not + provide the isolation levels READ UNCOMMITTED + and REPEATABLE READ. Because of multiversion + concurrency control, the SERIALIZABLE level is + not truly serializable. See for details. + - - is the default transaction isolation level in - SQL. PostgreSQL does - not provide the isolation levels - and . Because of multiversion - concurrency control, the level is not - truly serializable. See for details. - - - - In SQL there is one other transaction - characteristic that can be set with these commands: the size of - the diagnostics area. This concept is not supported in - PostgreSQL. - - + + In the SQL standard, there is one other transaction characteristic + that can be set with these commands: the size of the diagnostics + area. This concept is only for use in embedded SQL. + diff --git a/doc/src/sgml/ref/show.sgml b/doc/src/sgml/ref/show.sgml index 0fec5fcce5..dd8e9cf041 100644 --- a/doc/src/sgml/ref/show.sgml +++ b/doc/src/sgml/ref/show.sgml @@ -1,5 +1,5 @@ @@ -8,58 +8,34 @@ PostgreSQL documentation SHOW SQL - Language Statements + SHOW show the value of a run-time parameter + - + SHOW name - - + + SHOW ALL - - - - Inputs - - - - - name - - - The name of a run-time parameter. See - - for a list. - - - - - ALL - - - Show all current session parameters. - - - - - - - + - + Description + SHOW will display the current setting of run-time parameters. These variables can be set using the SET statement, by editing the - postgresql.conf configuration file, through the - PGOPTIONS environmental variable (when using libpq - or a libpq-based application), or through - command-line flags when starting the - postmaster. + postgresql.conf configuration file, through + the PGOPTIONS environmental variable (when using + libpq or a libpq-based + application), or through command-line flags when starting the + postmaster. See for details. @@ -67,83 +43,96 @@ SHOW ALL does not start a new transaction block. See the autocommit section in for details. + - - Available parameters are documented in - and on the - reference page. - In addition, there are a few parameters that can be shown but not set: + + Parameters - + + + name + + + The name of a run-time parameter. Available parameters are + documented in and on the reference page. In + addition, there are a few parameters that can be shown but not + set: - - SERVER_VERSION - - - Shows the server's version number. - - - + + + SERVER_VERSION + + + Shows the server's version number. + + + - - SERVER_ENCODING - - - Shows the server-side multibyte encoding. At present, this - parameter can be shown but not set, because the encoding is - determined at database creation time. - - - + + SERVER_ENCODING + + + Shows the server-side character set encoding. At present, + this parameter can be shown but not set, because the + encoding is determined at database creation time. + + + - - LC_COLLATE - - - Shows the database's locale setting for collation (text ordering). - At present, this parameter can be shown but not set, because the - setting is determined at initdb time. - - - + + LC_COLLATE + + + Shows the database's locale setting for collation (text + ordering). At present, this parameter can be shown but not + set, because the setting is determined at + initdb time. + + + - - LC_CTYPE - - - Shows the database's locale setting for character set considerations. - At present, this parameter can be shown but not set, because the - setting is determined at initdb time. - - - + + LC_CTYPE + + + Shows the database's locale setting for character + classification. At present, this parameter can be shown but + not set, because the setting is determined at + initdb time. + + + + + + + - - - - - Use to set the value - of settable parameters. - + + ALL + + + Show the values of all configurations parameters. + + + + Diagnostics - - - - ERROR: Option 'name' - is not recognized - - - Message returned if name does - not stand for a known parameter. - - - - - + + + ERROR: Option 'name' is not recognized + + + Message returned if name does not + stand for a known parameter. + + + + @@ -155,10 +144,11 @@ SHOW ALL - + Examples + - Show the current DateStyle setting: + Show the current setting of the parameter DateStyle: SHOW DateStyle; @@ -170,10 +160,9 @@ SHOW DateStyle; - Show whether the genetic query optimizer is enabled by displaying - the geqo setting: + Show the current setting of the parameter geqo: -SHOW GEQO; +SHOW geqo; geqo ------ on @@ -198,10 +187,9 @@ SHOW ALL; (94 rows) - - + Compatibility @@ -209,6 +197,15 @@ SHOW ALL; PostgreSQL extension. + + + See Also + + + + + + @@ -1384,9 +1384,10 @@ SET ENABLE_SEQSCAN TO OFF; date style - Sets the display format for date and time values, as well as the rules for - interpreting ambiguous date input values. - The default is ISO, US. + Sets the display format for date and time values, as well as + the rules for interpreting ambiguous date input values. See + for more information. The + default is ISO, US. @@ -1556,7 +1557,7 @@ dynamic_library_path = '/usr/local/lib/postgresql:/home/my_project/lib:$libdir' This parameter adjusts the number of digits displayed for floating-point values, including float4, float8, - and geometric datatypes. The parameter value is added to the + and geometric data types. The parameter value is added to the standard number of digits (FLT_DIG or DBL_DIG as appropriate). The value can be set as high as 2, to include partially-significant digits; this is especially useful for dumping @@ -1813,26 +1814,28 @@ dynamic_library_path = '/usr/local/lib/postgresql:/home/my_project/lib:$libdir' preload_libraries - This variable specifies one or more shared libraries that are to be - preloaded at Postmaster start. An initialization function can also be - optionally specified by adding a colon followed by the name of the - initialization function after the library name. For example - '$libdir/mylib:init_mylib' would cause mylib - to be preloaded and init_mylib to be executed. If more than - one library is to be loaded, they must be delimited with a comma. + This variable specifies one or more shared libraries that are + to be preloaded at server start. An initialization function + can also be optionally specified by adding a colon followed by + the name of the initialization function after the library + name. For example + '$libdir/mylib:init_mylib' would cause + mylib to be preloaded and init_mylib + to be executed. If more than one library is to be loaded, they + must be delimited with a comma. - If mylib is not found, the postmaster will fail to start. - However, if init_mylib is not found, mylib will - still be preloaded without executing the initialization function. + If mylib is not found, the server will fail to + start. However, if init_mylib is not found, + mylib will still be preloaded without executing + the initialization function. - By preloading a shared library (and initializing it if applicable), - the library startup time is avoided when the library is used later in a - specific backend. However there is a cost in terms of memory duplication - as every backend is forked, whether or not the library is used. + By preloading a shared library (and initializing it if + applicable), the library startup time is avoided when the + library is first used. @@ -2057,9 +2060,10 @@ dynamic_library_path = '/usr/local/lib/postgresql:/home/my_project/lib:$libdir' time zone - Sets the time zone for displaying and interpreting time stamps. - The default is to use whatever the system environment - specifies as the time zone. + Sets the time zone for displaying and interpreting time + stamps. The default is to use whatever the system environment + specifies as the time zone. See for more information.