From e1320266edd7df53c60af10b4c33ab2754278b3e Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Tue, 22 Nov 2016 17:56:16 -0500 Subject: [PATCH] Doc: improve documentation about composite-value usage. Create a section specifically for the syntactic rules around whole-row variable usage, such as expansion of "foo.*". This was previously documented only haphazardly, with some critical info buried in unexpected places like xfunc-sql-composite-functions. Per repeated questions in different mailing lists. Discussion: <16288.1479610770@sss.pgh.pa.us> --- doc/src/sgml/queries.sgml | 3 +- doc/src/sgml/rowtypes.sgml | 214 +++++++++++++++++++++++++++++++++++-- doc/src/sgml/syntax.sgml | 16 +-- doc/src/sgml/xfunc.sgml | 70 +++--------- 4 files changed, 231 insertions(+), 72 deletions(-) diff --git a/doc/src/sgml/queries.sgml b/doc/src/sgml/queries.sgml index 548f835830..5cc6dbce11 100644 --- a/doc/src/sgml/queries.sgml +++ b/doc/src/sgml/queries.sgml @@ -1457,7 +1457,8 @@ SELECT tbl1.a, tbl2.a, tbl1.b FROM ... SELECT tbl1.*, tbl2.a FROM ... - (See also .) + See for more about + the table_name.* notation. diff --git a/doc/src/sgml/rowtypes.sgml b/doc/src/sgml/rowtypes.sgml index 605dc71dab..9d6768e006 100644 --- a/doc/src/sgml/rowtypes.sgml +++ b/doc/src/sgml/rowtypes.sgml @@ -19,7 +19,7 @@ column of a table can be declared to be of a composite type. - + Declaration of Composite Types @@ -90,7 +90,7 @@ CREATE TABLE inventory_item ( - Composite Value Input + Constructing Composite Values composite type @@ -101,8 +101,9 @@ CREATE TABLE inventory_item ( To write a composite value as a literal constant, enclose the field values within parentheses and separate them by commas. You can put double quotes around any field value, and must do so if it contains commas or - parentheses. (More details appear below.) Thus, the general format of a - composite constant is the following: + parentheses. (More details appear below.) Thus, the general format of + a composite constant is the following: '( val1 , val2 , ... )' @@ -129,7 +130,8 @@ CREATE TABLE inventory_item ( the generic type constants discussed in . The constant is initially treated as a string and passed to the composite-type input conversion - routine. An explicit type specification might be necessary.) + routine. An explicit type specification might be necessary to tell + which type to convert the constant to.) @@ -143,7 +145,7 @@ ROW('fuzzy dice', 42, 1.99) ROW('', 42, NULL) The ROW keyword is actually optional as long as you have more than one - field in the expression, so these can simplify to: + field in the expression, so these can be simplified to: ('fuzzy dice', 42, 1.99) ('', 42, NULL) @@ -153,7 +155,7 @@ ROW('', 42, NULL) - + Accessing Composite Types @@ -198,6 +200,11 @@ SELECT (my_func(...)).field FROM ... Without the extra parentheses, this will generate a syntax error. + + + The special field name * means all fields, as + further explained in . + @@ -243,6 +250,199 @@ INSERT INTO mytab (complex_col.r, complex_col.i) VALUES(1.1, 2.2); + + Using Composite Types in Queries + + + There are various special syntax rules and behaviors associated with + composite types in queries. These rules provide useful shortcuts, + but can be confusing if you don't know the logic behind them. + + + + In PostgreSQL, a reference to a table name (or alias) + in a query is effectively a reference to the composite value of the + table's current row. For example, if we had a table + inventory_item as shown + above, we could write: + +SELECT c FROM inventory_item c; + + This query produces a single composite-valued column, so we might get + output like: + + c +------------------------ + ("fuzzy dice",42,1.99) +(1 row) + + Note however that simple names are matched to column names before table + names, so this example works only because there is no column + named c in the query's tables. + + + + The ordinary qualified-column-name + syntax table_name.column_name + can be understood as applying field + selection to the composite value of the table's current row. + (For efficiency reasons, it's not actually implemented that way.) + + + + When we write + +SELECT c.* FROM inventory_item c; + + then, according to the SQL standard, we should get the contents of the + table expanded into separate columns: + + name | supplier_id | price +------------+-------------+------- + fuzzy dice | 42 | 1.99 +(1 row) + + as if the query were + +SELECT c.name, c.supplier_id, c.price FROM inventory_item c; + + PostgreSQL will apply this expansion behavior to + any composite-valued expression, although as shown above, you need to write parentheses + around the value that .* is applied to whenever it's not a + simple table name. For example, if myfunc() is a function + returning a composite type with columns a, + b, and c, then these two queries have the + same result: + +SELECT (myfunc(x)).* FROM some_table; +SELECT (myfunc(x)).a, (myfunc(x)).b, (myfunc(x)).c FROM some_table; + + + + + + PostgreSQL handles column expansion by + actually transforming the first form into the second. So, in this + example, myfunc() would get invoked three times per row + with either syntax. If it's an expensive function you may wish to + avoid that, which you can do with a query like: + +SELECT (m).* FROM (SELECT myfunc(x) AS m FROM some_table OFFSET 0) ss; + + The OFFSET 0 clause keeps the optimizer + from flattening the sub-select to arrive at the form with + multiple calls of myfunc(). + + + + + The composite_value.* syntax results in + column expansion of this kind when it appears at the top level of + a SELECT output + list, a RETURNING + list in INSERT/UPDATE/DELETE, + a VALUES clause, or + a row constructor. + In all other contexts (including when nested inside one of those + constructs), attaching .* to a composite value does not + change the value, since it means all columns and so the + same composite value is produced again. For example, + if somefunc() accepts a composite-valued argument, + these queries are the same: + + +SELECT somefunc(c.*) FROM inventory_item c; +SELECT somefunc(c) FROM inventory_item c; + + + In both cases, the current row of inventory_item is + passed to the function as a single composite-valued argument. + Even though .* does nothing in such cases, using it is good + style, since it makes clear that a composite value is intended. In + particular, the parser will consider c in c.* to + refer to a table name or alias, not to a column name, so that there is + no ambiguity; whereas without .*, it is not clear + whether c means a table name or a column name, and in fact + the column-name interpretation will be preferred if there is a column + named c. + + + + Another example demonstrating these concepts is that all these queries + mean the same thing: + +SELECT * FROM inventory_item c ORDER BY c; +SELECT * FROM inventory_item c ORDER BY c.*; +SELECT * FROM inventory_item c ORDER BY ROW(c.*); + + All of these ORDER BY clauses specify the row's composite + value, resulting in sorting the rows according to the rules described + in . However, + if inventory_item contained a column + named c, the first case would be different from the + others, as it would mean to sort by that column only. Given the column + names previously shown, these queries are also equivalent to those above: + +SELECT * FROM inventory_item c ORDER BY ROW(c.name, c.supplier_id, c.price); +SELECT * FROM inventory_item c ORDER BY (c.name, c.supplier_id, c.price); + + (The last case uses a row constructor with the key word ROW + omitted.) + + + + Another special syntactical behavior associated with composite values is + that we can use functional notation for extracting a field + of a composite value. The simple way to explain this is that + the notations field(table) + and table.field + are interchangeable. For example, these queries are equivalent: + + +SELECT c.name FROM inventory_item c WHERE c.price > 1000; +SELECT name(c) FROM inventory_item c WHERE price(c) > 1000; + + + Moreover, if we have a function that accepts a single argument of a + composite type, we can call it with either notation. These queries are + all equivalent: + + +SELECT somefunc(c) FROM inventory_item c; +SELECT somefunc(c.*) FROM inventory_item c; +SELECT c.somefunc FROM inventory_item c; + + + + + This equivalence between functional notation and field notation + makes it possible to use functions on composite types to implement + computed fields. + + computed field + + + field + computed + + An application using the last query above wouldn't need to be directly + aware that somefunc isn't a real column of the table. + + + + + Because of this behavior, it's unwise to give a function that takes a + single composite-type argument the same name as any of the fields of + that composite type. If there is ambiguity, the field-name + interpretation will be preferred, so that such a function could not be + called without tricks. One way to force the function interpretation is + to schema-qualify the function name, that is, write + schema.func(compositevalue). + + + + Composite Type Input and Output Syntax diff --git a/doc/src/sgml/syntax.sgml b/doc/src/sgml/syntax.sgml index 36df6c6b1b..000da39250 100644 --- a/doc/src/sgml/syntax.sgml +++ b/doc/src/sgml/syntax.sgml @@ -1449,12 +1449,13 @@ $1.somecolumn - In a select list (see ), you - can ask for all fields of a composite value by + You can ask for all fields of a composite value by writing .*: (compositecol).* + This notation behaves differently depending on context; + see for details. @@ -1531,7 +1532,7 @@ sqrt(2) interchangeable. This behavior is not SQL-standard but is provided in PostgreSQL because it allows use of functions to emulate computed fields. For more information see - . + . @@ -2291,7 +2292,8 @@ SELECT ROW(1,2.5,'this is a test'); rowvalue.*, which will be expanded to a list of the elements of the row value, just as occurs when the .* syntax is used at the top level - of a SELECT list. For example, if table t has + of a SELECT list (see ). + For example, if table t has columns f1 and f2, these are the same: SELECT ROW(t.*, 42) FROM t; @@ -2302,9 +2304,9 @@ SELECT ROW(t.f1, t.f2, 42) FROM t; Before PostgreSQL 8.2, the - .* syntax was not expanded, so that writing - ROW(t.*, 42) created a two-field row whose first field - was another row value. The new behavior is usually more useful. + .* syntax was not expanded in row constructors, so + that writing ROW(t.*, 42) created a two-field row whose first + field was another row value. The new behavior is usually more useful. If you need the old behavior of nested row values, write the inner row value without .*, for instance ROW(t, 42). diff --git a/doc/src/sgml/xfunc.sgml b/doc/src/sgml/xfunc.sgml index 783702a637..f2f379870f 100644 --- a/doc/src/sgml/xfunc.sgml +++ b/doc/src/sgml/xfunc.sgml @@ -394,8 +394,8 @@ SELECT name, double_salary(emp.*) AS dream Notice the use of the syntax $1.salary to select one field of the argument row value. Also notice - how the calling SELECT command uses * - to select + how the calling SELECT command + uses table_name.* to select the entire current row of a table as a composite value. The table row can alternatively be referenced using just the table name, like this: @@ -405,6 +405,8 @@ SELECT name, double_salary(emp) AS dream WHERE emp.cubicle ~= point '(2,1)'; but this usage is deprecated since it's easy to get confused. + (See for details about these + two notations for the composite value of a table row.) @@ -479,7 +481,8 @@ $$ LANGUAGE SQL; - We could call this function directly in either of two ways: + We could call this function directly either by using it in + a value expression: SELECT new_emp(); @@ -487,7 +490,11 @@ SELECT new_emp(); new_emp -------------------------- (None,1000.0,25,"(2,2)") + + + or by calling it as a table function: + SELECT * FROM new_emp(); name | salary | age | cubicle @@ -524,12 +531,7 @@ LINE 1: SELECT new_emp().name; - Another option is to use - functional notation for extracting an attribute. The simple way - to explain this is that we can use the - notations attribute(table) - and table.attribute - interchangeably. + Another option is to use functional notation for extracting an attribute: SELECT name(new_emp()); @@ -539,50 +541,10 @@ SELECT name(new_emp()); None - --- This is the same as: --- SELECT emp.name AS youngster FROM emp WHERE emp.age < 30; - -SELECT name(emp) AS youngster FROM emp WHERE age(emp) < 30; - - youngster ------------ - Sam - Andy - + As explained in , the field notation and + functional notation are equivalent. - - - The equivalence between functional notation and attribute notation - makes it possible to use functions on composite types to emulate - computed fields. - - computed field - - - field - computed - - For example, using the previous definition - for double_salary(emp), we can write - - -SELECT emp.name, emp.double_salary FROM emp; - - - An application using this wouldn't need to be directly aware that - double_salary isn't a real column of the table. - (You can also emulate computed fields with views.) - - - - Because of this behavior, it's unwise to give a function that takes - a single composite-type argument the same name as any of the fields of - that composite type. - - - Another way to use a function returning a composite type is to pass the result to another function that accepts the correct row type as input: @@ -599,12 +561,6 @@ SELECT getname(new_emp()); (1 row) - - - Still another way to use a function that returns a composite type is to - call it as a table function, as described in . - -- 2.40.0