1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290
|
<html>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=ISO-8859-1">
<title>8.11.Composite Types</title>
<link rel="stylesheet" href="stylesheet.css" type="text/css">
<link rev="made" href="pgsql-docs@postgresql.org">
<meta name="generator" content="DocBook XSL Stylesheets V1.70.0">
<link rel="start" href="index.html" title="PostgreSQL 8.1.4 Documentation">
<link rel="up" href="datatype.html" title="Chapter8.Data Types">
<link rel="prev" href="arrays.html" title="8.10.Arrays">
<link rel="next" href="datatype-oid.html" title="8.12.Object Identifier Types">
<link rel="copyright" href="ln-legalnotice.html" title="Legal Notice">
</head>
<body bgcolor="white" text="black" link="#0000FF" vlink="#840084" alink="#0000FF"><div class="sect1" lang="en">
<div class="titlepage"><div><div><h2 class="title" style="clear: both">
<a name="rowtypes"></a>8.11.Composite Types</h2></div></div></div>
<a name="id592380"></a><a name="id592386"></a><p> A <em class="firstterm">composite type</em> describes the structure of a row or record;
it is in essence just a list of field names and their data types.
<span class="productname">PostgreSQL</span> allows values of composite types to be
used in many of the same ways that simple types can be used. For example, a
column of a table can be declared to be of a composite type.
</p>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="id592411"></a>8.11.1.Declaration of Composite Types</h3></div></div></div>
<p> Here are two simple examples of defining composite types:
</p>
<pre class="programlisting">CREATE TYPE complex AS (
r double precision,
i double precision
);
CREATE TYPE inventory_item AS (
name text,
supplier_id integer,
price numeric
);</pre>
<p>
The syntax is comparable to <code class="command">CREATE TABLE</code>, except that only
field names and types can be specified; no constraints (such as <code class="literal">NOT
NULL</code>) can presently be included. Note that the <code class="literal">AS</code> keyword
is essential; without it, the system will think a quite different kind
of <code class="command">CREATE TYPE</code> command is meant, and you'll get odd syntax
errors.
</p>
<p> Having defined the types, we can use them to create tables:
</p>
<pre class="programlisting">CREATE TABLE on_hand (
item inventory_item,
count integer
);
INSERT INTO on_hand VALUES (ROW('fuzzy dice', 42, 1.99), 1000);</pre>
<p>
or functions:
</p>
<pre class="programlisting">CREATE FUNCTION price_extension(inventory_item, integer) RETURNS numeric
AS 'SELECT $1.price * $2' LANGUAGE SQL;
SELECT price_extension(item, 10) FROM on_hand;</pre>
<p>
</p>
<p> Whenever you create a table, a composite type is also automatically
created, with the same name as the table, to represent the table's
row type. For example, had we said
</p>
<pre class="programlisting">CREATE TABLE inventory_item (
name text,
supplier_id integer REFERENCES suppliers,
price numeric CHECK (price > 0)
);</pre>
<p>
then the same <code class="literal">inventory_item</code> composite type shown above would
come into being as a
byproduct, and could be used just as above. Note however an important
restriction of the current implementation: since no constraints are
associated with a composite type, the constraints shown in the table
definition <span class="emphasis"><em>do not apply</em></span> to values of the composite type
outside the table. (A partial workaround is to use domain
types as members of composite types.)
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="id592516"></a>8.11.2.Composite Value Input</h3></div></div></div>
<a name="id592520"></a><p> To write a composite value as a literal constant, enclose the field
values within parentheses and separate them by commas. You may 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:
</p>
<pre class="synopsis">'( <em class="replaceable"><code>val1</code></em> , <em class="replaceable"><code>val2</code></em> , ... )'</pre>
<p>
An example is
</p>
<pre class="programlisting">'("fuzzy dice",42,1.99)'</pre>
<p>
which would be a valid value of the <code class="literal">inventory_item</code> type
defined above. To make a field be NULL, write no characters at all
in its position in the list. For example, this constant specifies
a NULL third field:
</p>
<pre class="programlisting">'("fuzzy dice",42,)'</pre>
<p>
If you want an empty string rather than NULL, write double quotes:
</p>
<pre class="programlisting">'("",42,)'</pre>
<p>
Here the first field is a non-NULL empty string, the third is NULL.
</p>
<p> (These constants are actually only a special case of
the generic type constants discussed in <a href="sql-syntax.html#sql-syntax-constants-generic" title="4.1.2.5.Constants of Other Types">Section4.1.2.5, “Constants of Other Types”</a>. The constant is initially
treated as a string and passed to the composite-type input conversion
routine. An explicit type specification might be necessary.)
</p>
<p> The <code class="literal">ROW</code> expression syntax may also be used to
construct composite values. In most cases this is considerably
simpler to use than the string-literal syntax, since you don't have
to worry about multiple layers of quoting. We already used this
method above:
</p>
<pre class="programlisting">ROW('fuzzy dice', 42, 1.99)
ROW('', 42, NULL)</pre>
<p>
The ROW keyword is actually optional as long as you have more than one
field in the expression, so these can simplify to
</p>
<pre class="programlisting">('fuzzy dice', 42, 1.99)
('', 42, NULL)</pre>
<p>
The <code class="literal">ROW</code> expression syntax is discussed in more detail in <a href="sql-expressions.html#sql-syntax-row-constructors" title="4.2.11.Row Constructors">Section4.2.11, “Row Constructors”</a>.
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="id592645"></a>8.11.3.Accessing Composite Types</h3></div></div></div>
<p> To access a field of a composite column, one writes a dot and the field
name, much like selecting a field from a table name. In fact, it's so
much like selecting from a table name that you often have to use parentheses
to keep from confusing the parser. For example, you might try to select
some subfields from our <code class="literal">on_hand</code> example table with something
like:
</p>
<pre class="programlisting">SELECT item.name FROM on_hand WHERE item.price > 9.99;</pre>
<p>
This will not work since the name <code class="literal">item</code> is taken to be a table
name, not a field name, per SQL syntax rules. You must write it like this:
</p>
<pre class="programlisting">SELECT (item).name FROM on_hand WHERE (item).price > 9.99;</pre>
<p>
or if you need to use the table name as well (for instance in a multitable
query), like this:
</p>
<pre class="programlisting">SELECT (on_hand.item).name FROM on_hand WHERE (on_hand.item).price > 9.99;</pre>
<p>
Now the parenthesized object is correctly interpreted as a reference to
the <code class="literal">item</code> column, and then the subfield can be selected from it.
</p>
<p> Similar syntactic issues apply whenever you select a field from a composite
value. For instance, to select just one field from the result of a function
that returns a composite value, you'd need to write something like
</p>
<pre class="programlisting">SELECT (my_func(...)).field FROM ...</pre>
<p>
Without the extra parentheses, this will provoke a syntax error.
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="id592723"></a>8.11.4.Modifying Composite Types</h3></div></div></div>
<p> Here are some examples of the proper syntax for inserting and updating
composite columns.
First, inserting or updating a whole column:
</p>
<pre class="programlisting">INSERT INTO mytab (complex_col) VALUES((1.1,2.2));
UPDATE mytab SET complex_col = ROW(1.1,2.2) WHERE ...;</pre>
<p>
The first example omits <code class="literal">ROW</code>, the second uses it; we
could have done it either way.
</p>
<p> We can update an individual subfield of a composite column:
</p>
<pre class="programlisting">UPDATE mytab SET complex_col.r = (complex_col).r + 1 WHERE ...;</pre>
<p>
Notice here that we don't need to (and indeed cannot)
put parentheses around the column name appearing just after
<code class="literal">SET</code>, but we do need parentheses when referencing the same
column in the expression to the right of the equal sign.
</p>
<p> And we can specify subfields as targets for <code class="command">INSERT</code>, too:
</p>
<pre class="programlisting">INSERT INTO mytab (complex_col.r, complex_col.i) VALUES(1.1, 2.2);</pre>
<p>
Had we not supplied values for all the subfields of the column, the
remaining subfields would have been filled with null values.
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="id592789"></a>8.11.5.Composite Type Input and Output Syntax</h3></div></div></div>
<p> The external text representation of a composite value consists of items that
are interpreted according to the I/O conversion rules for the individual
field types, plus decoration that indicates the composite structure.
The decoration consists of parentheses (<code class="literal">(</code> and <code class="literal">)</code>)
around the whole value, plus commas (<code class="literal">,</code>) between adjacent
items. Whitespace outside the parentheses is ignored, but within the
parentheses it is considered part of the field value, and may or may not be
significant depending on the input conversion rules for the field data type.
For example, in
</p>
<pre class="programlisting">'( 42)'</pre>
<p>
the whitespace will be ignored if the field type is integer, but not if
it is text.
</p>
<p> As shown previously, when writing a composite value you may write double
quotes around any individual field value.
You <span class="emphasis"><em>must</em></span> do so if the field value would otherwise
confuse the composite-value parser. In particular, fields containing
parentheses, commas, double quotes, or backslashes must be double-quoted.
To put a double quote or backslash in a quoted composite field value,
precede it with a backslash. (Also, a pair of double quotes within a
double-quoted field value is taken to represent a double quote character,
analogously to the rules for single quotes in SQL literal strings.)
Alternatively, you can use backslash-escaping to protect all data characters
that would otherwise be taken as composite syntax.
</p>
<p> A completely empty field value (no characters at all between the commas
or parentheses) represents a NULL. To write a value that is an empty
string rather than NULL, write <code class="literal">""</code>.
</p>
<p> The composite output routine will put double quotes around field values
if they are empty strings or contain parentheses, commas,
double quotes, backslashes, or white space. (Doing so for white space
is not essential, but aids legibility.) Double quotes and backslashes
embedded in field values will be doubled.
</p>
<div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Note</h3>
<p> Remember that what you write in an SQL command will first be interpreted
as a string literal, and then as a composite. This doubles the number of
backslashes you need. For example, to insert a <code class="type">text</code> field
containing a double quote and a backslash in a composite
value, you'd need to write
</p>
<pre class="programlisting">INSERT ... VALUES ('("\\"\\\\")');</pre>
<p>
The string-literal processor removes one level of backslashes, so that
what arrives at the composite-value parser looks like
<code class="literal">("\"\\")</code>. In turn, the string
fed to the <code class="type">text</code> data type's input routine
becomes <code class="literal">"\</code>. (If we were working
with a data type whose input routine also treated backslashes specially,
<code class="type">bytea</code> for example, we might need as many as eight backslashes
in the command to get one backslash into the stored composite field.)
Dollar quoting (see <a href="sql-syntax.html#sql-syntax-dollar-quoting" title="4.1.2.2.Dollar-Quoted String Constants">Section4.1.2.2, “Dollar-Quoted String Constants”</a>) may be
used to avoid the need to double backslashes.
</p>
</div>
<div class="tip" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Tip</h3>
<p> The <code class="literal">ROW</code> constructor syntax is usually easier to work with
than the composite-literal syntax when writing composite values in SQL
commands.
In <code class="literal">ROW</code>, individual field values are written the same way
they would be written when not members of a composite.
</p>
</div>
</div>
</div></body>
</html>
|