From 3c64342c861c77504df6c195c9db3e166d0c7491 Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Mon, 17 Sep 2012 14:59:31 -0400 Subject: [PATCH] Provide adequate documentation of the "table_name *" notation. Somewhere along the line, somebody decided to remove all trace of this notation from the documentation text. It was still in the command syntax synopses, or at least some of them, but with no indication what it meant. This will not do, as evidenced by the confusion apparent in bug #7543; even if the notation is now unnecessary, people will find it in legacy SQL code and need to know what it does. --- doc/src/sgml/config.sgml | 22 +++++++++++++----- doc/src/sgml/ddl.sgml | 37 ++++++++++++++++++------------- doc/src/sgml/queries.sgml | 10 +++++++++ doc/src/sgml/ref/alter_table.sgml | 12 +++++----- doc/src/sgml/ref/delete.sgml | 27 +++++++--------------- doc/src/sgml/ref/lock.sgml | 10 +++++---- doc/src/sgml/ref/select.sgml | 33 ++++++++++++++++++--------- doc/src/sgml/ref/truncate.sgml | 12 +++++----- doc/src/sgml/ref/update.sgml | 14 +++++------- 9 files changed, 104 insertions(+), 73 deletions(-) diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml index ade9f7974d..cfdc803056 100644 --- a/doc/src/sgml/config.sgml +++ b/doc/src/sgml/config.sgml @@ -5761,11 +5761,23 @@ dynamic_library_path = 'C:\tools\postgresql;H:\my_project\lib;$libdir' inheritance - This controls the inheritance semantics. If turned off, - subtables are not accessed by various commands by default; basically - an implied ONLY key word. This was added for - compatibility with releases prior to 7.1. See - for more information. + This setting controls whether undecorated table references are + considered to include inheritance child tables. The default is + on, which means child tables are included (thus, + a * suffix is assumed by default). If turned + off, child tables are not included (thus, an + ONLY prefix is assumed). The SQL standard + requires child tables to be included, so the off setting + is not spec-compliant, but it is provided for compatibility with + PostgreSQL releases prior to 7.1. + See for more information. + + + + Turning sql_inheritance off is deprecated, because that + behavior has been found to be error-prone as well as contrary to SQL + standard. Discussions of inheritance behavior elsewhere in this + manual generally assume that it is on. diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index 07bfc203ec..d6e5d646ee 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -2073,6 +2073,23 @@ SELECT name, altitude ONLY keyword. + + You can also write the table name with a trailing * + to explicitly specify that descendant tables are included: + + +SELECT name, altitude + FROM cities* + WHERE altitude > 500; + + + Writing * is not necessary, since this behavior is + the default (unless you have changed the setting of the + configuration option). + However writing * might be useful to emphasize that + additional tables will be searched. + + In some cases you might wish to know which table a particular row originated from. There is a system column called @@ -2220,15 +2237,15 @@ VALUES ('New York', NULL, NULL, 'NY'); data modification, or schema modification (e.g., SELECT, UPDATE, DELETE, most variants of ALTER TABLE, but - not INSERT and ALTER TABLE ... + not INSERT or ALTER TABLE ... RENAME) typically default to including child tables and support the ONLY notation to exclude them. Commands that do database maintenance and tuning (e.g., REINDEX, VACUUM) - typically only work on individual, physical tables and do no + typically only work on individual, physical tables and do not support recursing over inheritance hierarchies. The respective - behavior of each individual command is documented in the reference - part (). + behavior of each individual command is documented in its reference + page (). @@ -2278,18 +2295,6 @@ VALUES ('New York', NULL, NULL, 'NY'); inheritance is useful for your application. - - Deprecated - - In releases of PostgreSQL prior to 7.1, the - default behavior was not to include child tables in queries. This was - found to be error prone and also in violation of the SQL - standard. You can get the pre-7.1 behavior by turning off the - configuration - option. - - - diff --git a/doc/src/sgml/queries.sgml b/doc/src/sgml/queries.sgml index e34dfc0c5a..bcee946824 100644 --- a/doc/src/sgml/queries.sgml +++ b/doc/src/sgml/queries.sgml @@ -140,6 +140,16 @@ FROM table_reference , table_r — any columns added in subtables are ignored. + + Instead of writing ONLY before the table name, you can write + * after the table name to explicitly specify that descendant + tables are included. Writing * is not necessary since that + behavior is the default (unless you have changed the setting of the configuration option). However writing + * might be useful to emphasize that additional tables will be + searched. + + Joined Tables diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml index b7648142ee..356419e2d0 100644 --- a/doc/src/sgml/ref/alter_table.sgml +++ b/doc/src/sgml/ref/alter_table.sgml @@ -625,10 +625,12 @@ ALTER TABLE [ IF EXISTS ] name name - The name (possibly schema-qualified) of an existing table to - alter. If ONLY is specified, only that table is - altered. If ONLY is not specified, the table and any - descendant tables are altered. + The name (optionally schema-qualified) of an existing table to + alter. If ONLY is specified before the table name, only + that table is altered. If ONLY is not specified, the table + and all its descendant tables (if any) are altered. Optionally, + * can be specified after the table name to explicitly + indicate that descendant tables are included. @@ -1026,7 +1028,7 @@ ALTER TABLE distributors DROP CONSTRAINT zipchk; - To remove a check constraint from a table only: + To remove a check constraint from one table only: ALTER TABLE ONLY distributors DROP CONSTRAINT zipchk; diff --git a/doc/src/sgml/ref/delete.sgml b/doc/src/sgml/ref/delete.sgml index 2a9841d706..5d2ad3fde5 100644 --- a/doc/src/sgml/ref/delete.sgml +++ b/doc/src/sgml/ref/delete.sgml @@ -22,7 +22,7 @@ PostgreSQL documentation [ WITH [ RECURSIVE ] with_query [, ...] ] -DELETE FROM [ ONLY ] table_name [ [ AS ] alias ] +DELETE FROM [ ONLY ] table_name [ * ] [ [ AS ] alias ] [ USING using_list ] [ WHERE condition | WHERE CURRENT OF cursor_name ] [ RETURNING * | output_expression [ [ AS ] output_name ] [, ...] ] @@ -47,13 +47,6 @@ DELETE FROM [ ONLY ] table_name [ [ - - By default, DELETE will delete rows in the - specified table and all its child tables. If you wish to delete only - from the specific table mentioned, you must use the - ONLY clause. - - There are two ways to delete rows in a table using information contained in other tables in the database: using sub-selects, or @@ -96,21 +89,17 @@ DELETE FROM [ ONLY ] table_name [ [ - - ONLY - - - If specified, delete rows from the named table only. When not - specified, any tables inheriting from the named table are also processed. - - - - table_name - The name (optionally schema-qualified) of an existing table. + The name (optionally schema-qualified) of the table to delete rows + from. If ONLY is specified before the table name, + matching rows are deleted from the named table only. If + ONLY is not specified, matching rows are also deleted + from any tables inheriting from the named table. Optionally, + * can be specified after the table name to explicitly + indicate that descendant tables are included. diff --git a/doc/src/sgml/ref/lock.sgml b/doc/src/sgml/ref/lock.sgml index 53014ed34f..05acbc4f60 100644 --- a/doc/src/sgml/ref/lock.sgml +++ b/doc/src/sgml/ref/lock.sgml @@ -21,7 +21,7 @@ PostgreSQL documentation -LOCK [ TABLE ] [ ONLY ] name [, ...] [ IN lockmode MODE ] [ NOWAIT ] +LOCK [ TABLE ] [ ONLY ] name [ * ] [, ...] [ IN lockmode MODE ] [ NOWAIT ] where lockmode is one of: @@ -111,9 +111,11 @@ LOCK [ TABLE ] [ ONLY ] name [, ... The name (optionally schema-qualified) of an existing table to - lock. If ONLY is specified, only that table is - locked. If ONLY is not specified, the table and all - its descendant tables (if any) are locked. + lock. If ONLY is specified before the table name, only that + table is locked. If ONLY is not specified, the table and all + its descendant tables (if any) are locked. Optionally, * + can be specified after the table name to explicitly indicate that + descendant tables are included. diff --git a/doc/src/sgml/ref/select.sgml b/doc/src/sgml/ref/select.sgml index 0ac37a394f..9963780c31 100644 --- a/doc/src/sgml/ref/select.sgml +++ b/doc/src/sgml/ref/select.sgml @@ -298,10 +298,12 @@ TABLE [ ONLY ] table_name [ * ] 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 - any descendant tables are scanned. + The name (optionally schema-qualified) of an existing table or view. + If ONLY is specified before the table name, only that + table is scanned. If ONLY is not specified, the table + and all its descendant tables (if any) are scanned. Optionally, + * can be specified after the table name to explicitly + indicate that descendant tables are included. @@ -1661,15 +1663,24 @@ SELECT distributors.* WHERE distributors.name = 'Westward'; - <literal>ONLY</literal> and Parentheses + <literal>ONLY</literal> and Inheritance - The SQL standard requires parentheses around the table name - after ONLY, as in SELECT * FROM ONLY - (tab1), ONLY (tab2) WHERE .... PostgreSQL supports that - as well, but the parentheses are optional. (This point applies - equally to all SQL commands supporting the ONLY - option.) + The SQL standard requires parentheses around the table name when + writing ONLY, for example SELECT * FROM ONLY + (tab1), ONLY (tab2) WHERE .... PostgreSQL + considers these parentheses to be optional. + + + + PostgreSQL allows a trailing * to be written to + explicitly specify the non-ONLY behavior of including + child tables. The standard does not allow this. + + + + (These points apply equally to all SQL commands supporting the + ONLY option.) diff --git a/doc/src/sgml/ref/truncate.sgml b/doc/src/sgml/ref/truncate.sgml index 2fe47ca816..7b9c2f3012 100644 --- a/doc/src/sgml/ref/truncate.sgml +++ b/doc/src/sgml/ref/truncate.sgml @@ -21,7 +21,7 @@ PostgreSQL documentation -TRUNCATE [ TABLE ] [ ONLY ] name [, ... ] +TRUNCATE [ TABLE ] [ ONLY ] name [ * ] [, ... ] [ RESTART IDENTITY | CONTINUE IDENTITY ] [ CASCADE | RESTRICT ] @@ -47,10 +47,12 @@ TRUNCATE [ TABLE ] [ ONLY ] name [, name - The name (optionally schema-qualified) of a table to be - truncated. If ONLY is specified, only that table is - truncated. If ONLY is not specified, the table and - all its descendant tables (if any) are truncated. + The name (optionally schema-qualified) of a table to truncate. + If ONLY is specified before the table name, only that table + is truncated. If ONLY is not specified, the table and all + its descendant tables (if any) are truncated. Optionally, * + can be specified after the table name to explicitly indicate that + descendant tables are included. diff --git a/doc/src/sgml/ref/update.sgml b/doc/src/sgml/ref/update.sgml index c575374dd0..90b92085cd 100644 --- a/doc/src/sgml/ref/update.sgml +++ b/doc/src/sgml/ref/update.sgml @@ -22,7 +22,7 @@ PostgreSQL documentation [ WITH [ RECURSIVE ] with_query [, ...] ] -UPDATE [ ONLY ] table_name [ [ AS ] alias ] +UPDATE [ ONLY ] table_name [ * ] [ [ AS ] alias ] SET { column_name = { expression | DEFAULT } | ( column_name [, ...] ) = ( { expression | DEFAULT } [, ...] ) } [, ...] [ FROM from_list ] @@ -41,13 +41,6 @@ UPDATE [ ONLY ] table_name [ [ AS ] columns not explicitly modified retain their previous values. - - By default, UPDATE will update rows in the - specified table and all its subtables. If you wish to only update - the specific table mentioned, you must use the ONLY - clause. - - There are two ways to modify a table using information contained in other tables in the database: using sub-selects, or specifying @@ -97,6 +90,11 @@ UPDATE [ ONLY ] table_name [ [ AS ] The name (optionally schema-qualified) of the table to update. + If ONLY is specified before the table name, matching rows + are updated in the named table only. If ONLY is not + specified, matching rows are also updated in any tables inheriting from + the named table. Optionally, * can be specified after the + table name to explicitly indicate that descendant tables are included. -- 2.40.0