Allow specifying an access method for partitioned tables
[pgsql.git] / doc / src / sgml / ref / create_table.sgml
blobdfb7822985e446d61a074957355c468d8993eef0
1 <!--
2 doc/src/sgml/ref/create_table.sgml
3 PostgreSQL documentation
4 -->
6 <refentry id="sql-createtable">
7 <indexterm zone="sql-createtable">
8 <primary>CREATE TABLE</primary>
9 </indexterm>
11 <refmeta>
12 <refentrytitle>CREATE TABLE</refentrytitle>
13 <manvolnum>7</manvolnum>
14 <refmiscinfo>SQL - Language Statements</refmiscinfo>
15 </refmeta>
17 <refnamediv>
18 <refname>CREATE TABLE</refname>
19 <refpurpose>define a new table</refpurpose>
20 </refnamediv>
22 <refsynopsisdiv>
23 <synopsis>
24 CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXISTS ] <replaceable class="parameter">table_name</replaceable> ( [
25 { <replaceable class="parameter">column_name</replaceable> <replaceable class="parameter">data_type</replaceable> [ STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN | DEFAULT } ] [ COMPRESSION <replaceable>compression_method</replaceable> ] [ COLLATE <replaceable>collation</replaceable> ] [ <replaceable class="parameter">column_constraint</replaceable> [ ... ] ]
26 | <replaceable>table_constraint</replaceable>
27 | LIKE <replaceable>source_table</replaceable> [ <replaceable>like_option</replaceable> ... ] }
28 [, ... ]
29 ] )
30 [ INHERITS ( <replaceable>parent_table</replaceable> [, ... ] ) ]
31 [ PARTITION BY { RANGE | LIST | HASH } ( { <replaceable class="parameter">column_name</replaceable> | ( <replaceable class="parameter">expression</replaceable> ) } [ COLLATE <replaceable class="parameter">collation</replaceable> ] [ <replaceable class="parameter">opclass</replaceable> ] [, ... ] ) ]
32 [ USING <replaceable class="parameter">method</replaceable> ]
33 [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) | WITHOUT OIDS ]
34 [ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
35 [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
37 CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXISTS ] <replaceable class="parameter">table_name</replaceable>
38 OF <replaceable class="parameter">type_name</replaceable> [ (
39 { <replaceable class="parameter">column_name</replaceable> [ WITH OPTIONS ] [ <replaceable class="parameter">column_constraint</replaceable> [ ... ] ]
40 | <replaceable>table_constraint</replaceable> }
41 [, ... ]
42 ) ]
43 [ PARTITION BY { RANGE | LIST | HASH } ( { <replaceable class="parameter">column_name</replaceable> | ( <replaceable class="parameter">expression</replaceable> ) } [ COLLATE <replaceable class="parameter">collation</replaceable> ] [ <replaceable class="parameter">opclass</replaceable> ] [, ... ] ) ]
44 [ USING <replaceable class="parameter">method</replaceable> ]
45 [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) | WITHOUT OIDS ]
46 [ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
47 [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
49 CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXISTS ] <replaceable class="parameter">table_name</replaceable>
50 PARTITION OF <replaceable class="parameter">parent_table</replaceable> [ (
51 { <replaceable class="parameter">column_name</replaceable> [ WITH OPTIONS ] [ <replaceable class="parameter">column_constraint</replaceable> [ ... ] ]
52 | <replaceable>table_constraint</replaceable> }
53 [, ... ]
54 ) ] { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
55 [ PARTITION BY { RANGE | LIST | HASH } ( { <replaceable class="parameter">column_name</replaceable> | ( <replaceable class="parameter">expression</replaceable> ) } [ COLLATE <replaceable class="parameter">collation</replaceable> ] [ <replaceable class="parameter">opclass</replaceable> ] [, ... ] ) ]
56 [ USING <replaceable class="parameter">method</replaceable> ]
57 [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) | WITHOUT OIDS ]
58 [ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
59 [ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
61 <phrase>where <replaceable class="parameter">column_constraint</replaceable> is:</phrase>
63 [ CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> ]
64 { NOT NULL |
65 NULL |
66 CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
67 DEFAULT <replaceable>default_expr</replaceable> |
68 GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) STORED |
69 GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( <replaceable>sequence_options</replaceable> ) ] |
70 UNIQUE [ NULLS [ NOT ] DISTINCT ] <replaceable class="parameter">index_parameters</replaceable> |
71 PRIMARY KEY <replaceable class="parameter">index_parameters</replaceable> |
72 REFERENCES <replaceable class="parameter">reftable</replaceable> [ ( <replaceable class="parameter">refcolumn</replaceable> ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ]
73 [ ON DELETE <replaceable class="parameter">referential_action</replaceable> ] [ ON UPDATE <replaceable class="parameter">referential_action</replaceable> ] }
74 [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
76 <phrase>and <replaceable class="parameter">table_constraint</replaceable> is:</phrase>
78 [ CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> ]
79 { CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
80 NOT NULL <replaceable class="parameter">column_name</replaceable> [ NO INHERIT ] |
81 UNIQUE [ NULLS [ NOT ] DISTINCT ] ( <replaceable class="parameter">column_name</replaceable> [, ... ] [, <replaceable class="parameter">column_name</replaceable> WITHOUT OVERLAPS ] ) <replaceable class="parameter">index_parameters</replaceable> |
82 PRIMARY KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] [, <replaceable class="parameter">column_name</replaceable> WITHOUT OVERLAPS ] ) <replaceable class="parameter">index_parameters</replaceable> |
83 EXCLUDE [ USING <replaceable class="parameter">index_method</replaceable> ] ( <replaceable class="parameter">exclude_element</replaceable> WITH <replaceable class="parameter">operator</replaceable> [, ... ] ) <replaceable class="parameter">index_parameters</replaceable> [ WHERE ( <replaceable class="parameter">predicate</replaceable> ) ] |
84 FOREIGN KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] [, PERIOD <replaceable class="parameter">column_name</replaceable> ] ) REFERENCES <replaceable class="parameter">reftable</replaceable> [ ( <replaceable class="parameter">refcolumn</replaceable> [, ... ] [, PERIOD <replaceable class="parameter">column_name</replaceable> ] ) ]
85 [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ] [ ON DELETE <replaceable
86 class="parameter">referential_action</replaceable> ] [ ON UPDATE <replaceable class="parameter">referential_action</replaceable> ] }
87 [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
89 <phrase>and <replaceable class="parameter">like_option</replaceable> is:</phrase>
91 { INCLUDING | EXCLUDING } { COMMENTS | COMPRESSION | CONSTRAINTS | DEFAULTS | GENERATED | IDENTITY | INDEXES | STATISTICS | STORAGE | ALL }
93 <phrase>and <replaceable class="parameter">partition_bound_spec</replaceable> is:</phrase>
95 IN ( <replaceable class="parameter">partition_bound_expr</replaceable> [, ...] ) |
96 FROM ( { <replaceable class="parameter">partition_bound_expr</replaceable> | MINVALUE | MAXVALUE } [, ...] )
97 TO ( { <replaceable class="parameter">partition_bound_expr</replaceable> | MINVALUE | MAXVALUE } [, ...] ) |
98 WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REMAINDER <replaceable class="parameter">numeric_literal</replaceable> )
100 <phrase><replaceable class="parameter">index_parameters</replaceable> in <literal>UNIQUE</literal>, <literal>PRIMARY KEY</literal>, and <literal>EXCLUDE</literal> constraints are:</phrase>
102 [ INCLUDE ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) ]
103 [ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
104 [ USING INDEX TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
106 <phrase><replaceable class="parameter">exclude_element</replaceable> in an <literal>EXCLUDE</literal> constraint is:</phrase>
108 { <replaceable class="parameter">column_name</replaceable> | ( <replaceable class="parameter">expression</replaceable> ) } [ <replaceable class="parameter">opclass</replaceable> ] [ ASC | DESC ] [ NULLS { FIRST | LAST } ]
110 <phrase><replaceable class="parameter">referential_action</replaceable> in a <literal>FOREIGN KEY</literal>/<literal>REFERENCES</literal> constraint is:</phrase>
112 { NO ACTION | RESTRICT | CASCADE | SET NULL [ ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) ] | SET DEFAULT [ ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) ] }
113 </synopsis>
115 </refsynopsisdiv>
117 <refsect1 id="sql-createtable-description">
118 <title>Description</title>
120 <para>
121 <command>CREATE TABLE</command> will create a new, initially empty table
122 in the current database. The table will be owned by the user issuing the
123 command.
124 </para>
126 <para>
127 If a schema name is given (for example, <literal>CREATE TABLE
128 myschema.mytable ...</literal>) then the table is created in the specified
129 schema. Otherwise it is created in the current schema. Temporary
130 tables exist in a special schema, so a schema name cannot be given
131 when creating a temporary table. The name of the table must be
132 distinct from the name of any other relation (table, sequence, index, view,
133 materialized view, or foreign table) in the same schema.
134 </para>
136 <para>
137 <command>CREATE TABLE</command> also automatically creates a data
138 type that represents the composite type corresponding
139 to one row of the table. Therefore, tables cannot have the same
140 name as any existing data type in the same schema.
141 </para>
143 <para>
144 The optional constraint clauses specify constraints (tests) that
145 new or updated rows must satisfy for an insert or update operation
146 to succeed. A constraint is an SQL object that helps define the
147 set of valid values in the table in various ways.
148 </para>
150 <para>
151 There are two ways to define constraints: table constraints and
152 column constraints. A column constraint is defined as part of a
153 column definition. A table constraint definition is not tied to a
154 particular column, and it can encompass more than one column.
155 Every column constraint can also be written as a table constraint;
156 a column constraint is only a notational convenience for use when the
157 constraint only affects one column.
158 </para>
160 <para>
161 To be able to create a table, you must have <literal>USAGE</literal>
162 privilege on all column types or the type in the <literal>OF</literal>
163 clause, respectively.
164 </para>
165 </refsect1>
167 <refsect1>
168 <title>Parameters</title>
170 <variablelist>
172 <varlistentry id="sql-createtable-temporary">
173 <term><literal>TEMPORARY</literal> or <literal>TEMP</literal></term>
174 <listitem>
175 <para>
176 If specified, the table is created as a temporary table.
177 Temporary tables are automatically dropped at the end of a
178 session, or optionally at the end of the current transaction
179 (see <literal>ON COMMIT</literal> below). The default
180 search_path includes the temporary schema first and so identically
181 named existing permanent tables are not chosen for new plans
182 while the temporary table exists, unless they are referenced
183 with schema-qualified names. Any indexes created on a temporary
184 table are automatically temporary as well.
185 </para>
187 <para>
188 The <link linkend="autovacuum">autovacuum daemon</link> cannot
189 access and therefore cannot vacuum or analyze temporary tables.
190 For this reason, appropriate vacuum and analyze operations should be
191 performed via session SQL commands. For example, if a temporary
192 table is going to be used in complex queries, it is wise to run
193 <command>ANALYZE</command> on the temporary table after it is populated.
194 </para>
196 <para>
197 Optionally, <literal>GLOBAL</literal> or <literal>LOCAL</literal>
198 can be written before <literal>TEMPORARY</literal> or <literal>TEMP</literal>.
199 This presently makes no difference in <productname>PostgreSQL</productname>
200 and is deprecated; see
201 <xref linkend="sql-createtable-compatibility"/> below.
202 </para>
203 </listitem>
204 </varlistentry>
206 <varlistentry id="sql-createtable-unlogged">
207 <term><literal>UNLOGGED</literal></term>
208 <listitem>
209 <para>
210 If specified, the table is created as an unlogged table. Data written
211 to unlogged tables is not written to the write-ahead log (see <xref
212 linkend="wal"/>), which makes them considerably faster than ordinary
213 tables. However, they are not crash-safe: an unlogged table is
214 automatically truncated after a crash or unclean shutdown. The contents
215 of an unlogged table are also not replicated to standby servers.
216 Any indexes created on an unlogged table are automatically unlogged as
217 well.
218 </para>
220 <para>
221 If this is specified, any sequences created together with the unlogged
222 table (for identity or serial columns) are also created as unlogged.
223 </para>
224 </listitem>
225 </varlistentry>
227 <varlistentry id="sql-createtable-parms-if-not-exists">
228 <term><literal>IF NOT EXISTS</literal></term>
229 <listitem>
230 <para>
231 Do not throw an error if a relation with the same name already exists.
232 A notice is issued in this case. Note that there is no guarantee that
233 the existing relation is anything like the one that would have been
234 created.
235 </para>
236 </listitem>
237 </varlistentry>
239 <varlistentry id="sql-createtable-parms-table-name">
240 <term><replaceable class="parameter">table_name</replaceable></term>
241 <listitem>
242 <para>
243 The name (optionally schema-qualified) of the table to be created.
244 </para>
245 </listitem>
246 </varlistentry>
248 <varlistentry id="sql-createtable-parms-type-name">
249 <term><literal>OF <replaceable class="parameter">type_name</replaceable></literal></term>
250 <listitem>
251 <para>
252 Creates a <firstterm>typed table</firstterm>, which takes its
253 structure from the specified composite type (name optionally
254 schema-qualified). A typed table is tied to its type; for
255 example the table will be dropped if the type is dropped
256 (with <literal>DROP TYPE ... CASCADE</literal>).
257 </para>
259 <para>
260 When a typed table is created, then the data types of the
261 columns are determined by the underlying composite type and are
262 not specified by the <literal>CREATE TABLE</literal> command.
263 But the <literal>CREATE TABLE</literal> command can add defaults
264 and constraints to the table and can specify storage parameters.
265 </para>
266 </listitem>
267 </varlistentry>
269 <varlistentry id="sql-createtable-parms-column-name">
270 <term><replaceable class="parameter">column_name</replaceable></term>
271 <listitem>
272 <para>
273 The name of a column to be created in the new table.
274 </para>
275 </listitem>
276 </varlistentry>
278 <varlistentry id="sql-createtable-parms-data-type">
279 <term><replaceable class="parameter">data_type</replaceable></term>
280 <listitem>
281 <para>
282 The data type of the column. This can include array
283 specifiers. For more information on the data types supported by
284 <productname>PostgreSQL</productname>, refer to <xref
285 linkend="datatype"/>.
286 </para>
287 </listitem>
288 </varlistentry>
290 <varlistentry id="sql-createtable-parms-collate">
291 <term><literal>COLLATE <replaceable>collation</replaceable></literal></term>
292 <listitem>
293 <para>
294 The <literal>COLLATE</literal> clause assigns a collation to
295 the column (which must be of a collatable data type).
296 If not specified, the column data type's default collation is used.
297 </para>
298 </listitem>
299 </varlistentry>
301 <varlistentry id="sql-createtable-parms-storage">
302 <term>
303 <literal>STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN | DEFAULT }</literal>
304 <indexterm>
305 <primary>TOAST</primary>
306 <secondary>per-column storage settings</secondary>
307 </indexterm>
308 </term>
309 <listitem>
310 <para>
311 This form sets the storage mode for the column. This controls whether this
312 column is held inline or in a secondary <acronym>TOAST</acronym> table,
313 and whether the data should be compressed or not. <literal>PLAIN</literal>
314 must be used for fixed-length values such as <type>integer</type> and is
315 inline, uncompressed. <literal>MAIN</literal> is for inline, compressible
316 data. <literal>EXTERNAL</literal> is for external, uncompressed data, and
317 <literal>EXTENDED</literal> is for external, compressed data.
318 Writing <literal>DEFAULT</literal> sets the storage mode to the default
319 mode for the column's data type. <literal>EXTENDED</literal> is the
320 default for most data types that support non-<literal>PLAIN</literal>
321 storage.
322 Use of <literal>EXTERNAL</literal> will make substring operations on
323 very large <type>text</type> and <type>bytea</type> values run faster,
324 at the penalty of increased storage space.
325 See <xref linkend="storage-toast"/> for more information.
326 </para>
327 </listitem>
328 </varlistentry>
330 <varlistentry id="sql-createtable-parms-compression">
331 <term><literal>COMPRESSION <replaceable class="parameter">compression_method</replaceable></literal></term>
332 <listitem>
333 <para>
334 The <literal>COMPRESSION</literal> clause sets the compression method
335 for the column. Compression is supported only for variable-width data
336 types, and is used only when the column's storage mode
337 is <literal>main</literal> or <literal>extended</literal>.
338 (See <xref linkend="sql-altertable"/> for information on
339 column storage modes.) Setting this property for a partitioned table
340 has no direct effect, because such tables have no storage of their own,
341 but the configured value will be inherited by newly-created partitions.
342 The supported compression methods are <literal>pglz</literal> and
343 <literal>lz4</literal>. (<literal>lz4</literal> is available only if
344 <option>--with-lz4</option> was used when building
345 <productname>PostgreSQL</productname>.) In addition,
346 <replaceable class="parameter">compression_method</replaceable>
347 can be <literal>default</literal> to explicitly specify the default
348 behavior, which is to consult the
349 <xref linkend="guc-default-toast-compression"/> setting at the time of
350 data insertion to determine the method to use.
351 </para>
352 </listitem>
353 </varlistentry>
355 <varlistentry id="sql-createtable-parms-inherits">
356 <term><literal>INHERITS ( <replaceable>parent_table</replaceable> [, ... ] )</literal></term>
357 <listitem>
358 <para>
359 The optional <literal>INHERITS</literal> clause specifies a list of
360 tables from which the new table automatically inherits all
361 columns. Parent tables can be plain tables or foreign tables.
362 </para>
364 <para>
365 Use of <literal>INHERITS</literal> creates a persistent relationship
366 between the new child table and its parent table(s). Schema
367 modifications to the parent(s) normally propagate to children
368 as well, and by default the data of the child table is included in
369 scans of the parent(s).
370 </para>
372 <para>
373 If the same column name exists in more than one parent
374 table, an error is reported unless the data types of the columns
375 match in each of the parent tables. If there is no conflict,
376 then the duplicate columns are merged to form a single column in
377 the new table. If the column name list of the new table
378 contains a column name that is also inherited, the data type must
379 likewise match the inherited column(s), and the column
380 definitions are merged into one. If the
381 new table explicitly specifies a default value for the column,
382 this default overrides any defaults from inherited declarations
383 of the column. Otherwise, any parents that specify default
384 values for the column must all specify the same default, or an
385 error will be reported.
386 </para>
388 <para>
389 <literal>CHECK</literal> constraints are merged in essentially the same way as
390 columns: if multiple parent tables and/or the new table definition
391 contain identically-named <literal>CHECK</literal> constraints, these
392 constraints must all have the same check expression, or an error will be
393 reported. Constraints having the same name and expression will
394 be merged into one copy. A constraint marked <literal>NO INHERIT</literal> in a
395 parent will not be considered. Notice that an unnamed <literal>CHECK</literal>
396 constraint in the new table will never be merged, since a unique name
397 will always be chosen for it.
398 </para>
400 <para>
401 Column <literal>STORAGE</literal> settings are also copied from parent tables.
402 </para>
404 <para>
405 If a column in the parent table is an identity column, that property is
406 not inherited. A column in the child table can be declared identity
407 column if desired.
408 </para>
409 </listitem>
410 </varlistentry>
412 <varlistentry id="sql-createtable-parms-partition-by">
413 <term><literal>PARTITION BY { RANGE | LIST | HASH } ( { <replaceable class="parameter">column_name</replaceable> | ( <replaceable class="parameter">expression</replaceable> ) } [ <replaceable class="parameter">opclass</replaceable> ] [, ...] ) </literal></term>
414 <listitem>
415 <para>
416 The optional <literal>PARTITION BY</literal> clause specifies a strategy
417 of partitioning the table. The table thus created is called a
418 <firstterm>partitioned</firstterm> table. The parenthesized list of
419 columns or expressions forms the <firstterm>partition key</firstterm>
420 for the table. When using range or hash partitioning, the partition key
421 can include multiple columns or expressions (up to 32, but this limit can
422 be altered when building <productname>PostgreSQL</productname>), but for
423 list partitioning, the partition key must consist of a single column or
424 expression.
425 </para>
427 <para>
428 Range and list partitioning require a btree operator class, while hash
429 partitioning requires a hash operator class. If no operator class is
430 specified explicitly, the default operator class of the appropriate
431 type will be used; if no default operator class exists, an error will
432 be raised. When hash partitioning is used, the operator class used
433 must implement support function 2 (see <xref linkend="xindex-support"/>
434 for details).
435 </para>
437 <para>
438 A partitioned table is divided into sub-tables (called partitions),
439 which are created using separate <literal>CREATE TABLE</literal> commands.
440 The partitioned table is itself empty. A data row inserted into the
441 table is routed to a partition based on the value of columns or
442 expressions in the partition key. If no existing partition matches
443 the values in the new row, an error will be reported.
444 </para>
446 <para>
447 Partitioned tables do not support <literal>EXCLUDE</literal> constraints;
448 however, you can define these constraints on individual partitions.
449 </para>
451 <para>
452 See <xref linkend="ddl-partitioning"/> for more discussion on table
453 partitioning.
454 </para>
456 </listitem>
457 </varlistentry>
459 <varlistentry id="sql-createtable-partition">
460 <term><literal>PARTITION OF <replaceable class="parameter">parent_table</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }</literal></term>
461 <listitem>
462 <para>
463 Creates the table as a <firstterm>partition</firstterm> of the specified
464 parent table. The table can be created either as a partition for specific
465 values using <literal>FOR VALUES</literal> or as a default partition
466 using <literal>DEFAULT</literal>. Any indexes, constraints and
467 user-defined row-level triggers that exist in the parent table are cloned
468 on the new partition.
469 </para>
471 <para>
472 The <replaceable class="parameter">partition_bound_spec</replaceable>
473 must correspond to the partitioning method and partition key of the
474 parent table, and must not overlap with any existing partition of that
475 parent. The form with <literal>IN</literal> is used for list partitioning,
476 the form with <literal>FROM</literal> and <literal>TO</literal> is used
477 for range partitioning, and the form with <literal>WITH</literal> is used
478 for hash partitioning.
479 </para>
481 <para>
482 <replaceable class="parameter">partition_bound_expr</replaceable> is
483 any variable-free expression (subqueries, window functions, aggregate
484 functions, and set-returning functions are not allowed). Its data type
485 must match the data type of the corresponding partition key column.
486 The expression is evaluated once at table creation time, so it can
487 even contain volatile expressions such as
488 <literal><function>CURRENT_TIMESTAMP</function></literal>.
489 </para>
491 <para>
492 When creating a list partition, <literal>NULL</literal> can be
493 specified to signify that the partition allows the partition key
494 column to be null. However, there cannot be more than one such
495 list partition for a given parent table. <literal>NULL</literal>
496 cannot be specified for range partitions.
497 </para>
499 <para>
500 When creating a range partition, the lower bound specified with
501 <literal>FROM</literal> is an inclusive bound, whereas the upper
502 bound specified with <literal>TO</literal> is an exclusive bound.
503 That is, the values specified in the <literal>FROM</literal> list
504 are valid values of the corresponding partition key columns for this
505 partition, whereas those in the <literal>TO</literal> list are
506 not. Note that this statement must be understood according to the
507 rules of row-wise comparison (<xref linkend="row-wise-comparison"/>).
508 For example, given <literal>PARTITION BY RANGE (x,y)</literal>, a partition
509 bound <literal>FROM (1, 2) TO (3, 4)</literal>
510 allows <literal>x=1</literal> with any <literal>y&gt;=2</literal>,
511 <literal>x=2</literal> with any non-null <literal>y</literal>,
512 and <literal>x=3</literal> with any <literal>y&lt;4</literal>.
513 </para>
515 <para>
516 The special values <literal>MINVALUE</literal> and <literal>MAXVALUE</literal>
517 may be used when creating a range partition to indicate that there
518 is no lower or upper bound on the column's value. For example, a
519 partition defined using <literal>FROM (MINVALUE) TO (10)</literal> allows
520 any values less than 10, and a partition defined using
521 <literal>FROM (10) TO (MAXVALUE)</literal> allows any values greater than
522 or equal to 10.
523 </para>
525 <para>
526 When creating a range partition involving more than one column, it
527 can also make sense to use <literal>MAXVALUE</literal> as part of the lower
528 bound, and <literal>MINVALUE</literal> as part of the upper bound. For
529 example, a partition defined using
530 <literal>FROM (0, MAXVALUE) TO (10, MAXVALUE)</literal> allows any rows
531 where the first partition key column is greater than 0 and less than
532 or equal to 10. Similarly, a partition defined using
533 <literal>FROM ('a', MINVALUE) TO ('b', MINVALUE)</literal> allows any rows
534 where the first partition key column starts with "a".
535 </para>
537 <para>
538 Note that if <literal>MINVALUE</literal> or <literal>MAXVALUE</literal> is used for
539 one column of a partitioning bound, the same value must be used for all
540 subsequent columns. For example, <literal>(10, MINVALUE, 0)</literal> is not
541 a valid bound; you should write <literal>(10, MINVALUE, MINVALUE)</literal>.
542 </para>
544 <para>
545 Also note that some element types, such as <literal>timestamp</literal>,
546 have a notion of "infinity", which is just another value that can
547 be stored. This is different from <literal>MINVALUE</literal> and
548 <literal>MAXVALUE</literal>, which are not real values that can be stored,
549 but rather they are ways of saying that the value is unbounded.
550 <literal>MAXVALUE</literal> can be thought of as being greater than any
551 other value, including "infinity" and <literal>MINVALUE</literal> as being
552 less than any other value, including "minus infinity". Thus the range
553 <literal>FROM ('infinity') TO (MAXVALUE)</literal> is not an empty range; it
554 allows precisely one value to be stored &mdash; "infinity".
555 </para>
557 <para>
558 If <literal>DEFAULT</literal> is specified, the table will be
559 created as the default partition of the parent table. This option
560 is not available for hash-partitioned tables. A partition key value
561 not fitting into any other partition of the given parent will be
562 routed to the default partition.
563 </para>
565 <para>
566 When a table has an existing <literal>DEFAULT</literal> partition and
567 a new partition is added to it, the default partition must
568 be scanned to verify that it does not contain any rows which properly
569 belong in the new partition. If the default partition contains a
570 large number of rows, this may be slow. The scan will be skipped if
571 the default partition is a foreign table or if it has a constraint which
572 proves that it cannot contain rows which should be placed in the new
573 partition.
574 </para>
576 <para>
577 When creating a hash partition, a modulus and remainder must be specified.
578 The modulus must be a positive integer, and the remainder must be a
579 non-negative integer less than the modulus. Typically, when initially
580 setting up a hash-partitioned table, you should choose a modulus equal to
581 the number of partitions and assign every table the same modulus and a
582 different remainder (see examples, below). However, it is not required
583 that every partition have the same modulus, only that every modulus which
584 occurs among the partitions of a hash-partitioned table is a factor of the
585 next larger modulus. This allows the number of partitions to be increased
586 incrementally without needing to move all the data at once. For example,
587 suppose you have a hash-partitioned table with 8 partitions, each of which
588 has modulus 8, but find it necessary to increase the number of partitions
589 to 16. You can detach one of the modulus-8 partitions, create two new
590 modulus-16 partitions covering the same portion of the key space (one with
591 a remainder equal to the remainder of the detached partition, and the
592 other with a remainder equal to that value plus 8), and repopulate them
593 with data. You can then repeat this -- perhaps at a later time -- for
594 each modulus-8 partition until none remain. While this may still involve
595 a large amount of data movement at each step, it is still better than
596 having to create a whole new table and move all the data at once.
597 </para>
599 <para>
600 A partition must have the same column names and types as the partitioned
601 table to which it belongs. Modifications to the column names or types of
602 a partitioned table will automatically propagate to all partitions.
603 <literal>CHECK</literal> constraints will be inherited automatically by
604 every partition, but an individual partition may specify additional
605 <literal>CHECK</literal> constraints; additional constraints with the
606 same name and condition as in the parent will be merged with the parent
607 constraint. Defaults may be specified separately for each partition.
608 But note that a partition's default value is not applied when inserting
609 a tuple through a partitioned table.
610 </para>
612 <para>
613 Rows inserted into a partitioned table will be automatically routed to
614 the correct partition. If no suitable partition exists, an error will
615 occur.
616 </para>
618 <para>
619 Operations such as <command>TRUNCATE</command>
620 which normally affect a table and all of its
621 inheritance children will cascade to all partitions, but may also be
622 performed on an individual partition.
623 </para>
625 <para>
626 Note that creating a partition using <literal>PARTITION OF</literal>
627 requires taking an <literal>ACCESS EXCLUSIVE</literal> lock on the
628 parent partitioned table. Likewise, dropping a partition
629 with <command>DROP TABLE</command> requires taking
630 an <literal>ACCESS EXCLUSIVE</literal> lock on the parent table.
631 It is possible to use <link linkend="sql-altertable"><command>ALTER
632 TABLE ATTACH/DETACH PARTITION</command></link> to perform these
633 operations with a weaker lock, thus reducing interference with
634 concurrent operations on the partitioned table.
635 </para>
637 </listitem>
638 </varlistentry>
640 <varlistentry id="sql-createtable-parms-like">
641 <term><literal>LIKE <replaceable>source_table</replaceable> [ <replaceable>like_option</replaceable> ... ]</literal></term>
642 <listitem>
643 <para>
644 The <literal>LIKE</literal> clause specifies a table from which
645 the new table automatically copies all column names, their data types,
646 and their not-null constraints.
647 </para>
648 <para>
649 Unlike <literal>INHERITS</literal>, the new table and original table
650 are completely decoupled after creation is complete. Changes to the
651 original table will not be applied to the new table, and it is not
652 possible to include data of the new table in scans of the original
653 table.
654 </para>
655 <para>
656 Also unlike <literal>INHERITS</literal>, columns and
657 constraints copied by <literal>LIKE</literal> are not merged with similarly
658 named columns and constraints.
659 If the same name is specified explicitly or in another
660 <literal>LIKE</literal> clause, an error is signaled.
661 </para>
662 <para>
663 The optional <replaceable>like_option</replaceable> clauses specify
664 which additional properties of the original table to copy. Specifying
665 <literal>INCLUDING</literal> copies the property, specifying
666 <literal>EXCLUDING</literal> omits the property.
667 <literal>EXCLUDING</literal> is the default. If multiple specifications
668 are made for the same kind of object, the last one is used. The
669 available options are:
671 <variablelist>
672 <varlistentry id="sql-createtable-parms-like-opt-comments">
673 <term><literal>INCLUDING COMMENTS</literal></term>
674 <listitem>
675 <para>
676 Comments for the copied columns, constraints, and indexes will be
677 copied. The default behavior is to exclude comments, resulting in
678 the copied columns and constraints in the new table having no
679 comments.
680 </para>
681 </listitem>
682 </varlistentry>
684 <varlistentry id="sql-createtable-parms-like-opt-compression">
685 <term><literal>INCLUDING COMPRESSION</literal></term>
686 <listitem>
687 <para>
688 Compression method of the columns will be copied. The default
689 behavior is to exclude compression methods, resulting in columns
690 having the default compression method.
691 </para>
692 </listitem>
693 </varlistentry>
695 <varlistentry id="sql-createtable-parms-like-opt-constraints">
696 <term><literal>INCLUDING CONSTRAINTS</literal></term>
697 <listitem>
698 <para>
699 <literal>CHECK</literal> constraints will be copied. No distinction
700 is made between column constraints and table constraints. Not-null
701 constraints are always copied to the new table.
702 </para>
703 </listitem>
704 </varlistentry>
706 <varlistentry id="sql-createtable-parms-like-opt-defaults">
707 <term><literal>INCLUDING DEFAULTS</literal></term>
708 <listitem>
709 <para>
710 Default expressions for the copied column definitions will be
711 copied. Otherwise, default expressions are not copied, resulting in
712 the copied columns in the new table having null defaults. Note that
713 copying defaults that call database-modification functions, such as
714 <function>nextval</function>, may create a functional linkage
715 between the original and new tables.
716 </para>
717 </listitem>
718 </varlistentry>
720 <varlistentry id="sql-createtable-parms-like-opt-generated">
721 <term><literal>INCLUDING GENERATED</literal></term>
722 <listitem>
723 <para>
724 Any generation expressions of copied column definitions will be
725 copied. By default, new columns will be regular base columns.
726 </para>
727 </listitem>
728 </varlistentry>
730 <varlistentry id="sql-createtable-parms-like-opt-identity">
731 <term><literal>INCLUDING IDENTITY</literal></term>
732 <listitem>
733 <para>
734 Any identity specifications of copied column definitions will be
735 copied. A new sequence is created for each identity column of the
736 new table, separate from the sequences associated with the old
737 table.
738 </para>
739 </listitem>
740 </varlistentry>
742 <varlistentry id="sql-createtable-parms-like-opt-indexes">
743 <term><literal>INCLUDING INDEXES</literal></term>
744 <listitem>
745 <para>
746 Indexes, <literal>PRIMARY KEY</literal>, <literal>UNIQUE</literal>,
747 and <literal>EXCLUDE</literal> constraints on the original table
748 will be created on the new table. Names for the new indexes and
749 constraints are chosen according to the default rules, regardless of
750 how the originals were named. (This behavior avoids possible
751 duplicate-name failures for the new indexes.)
752 </para>
753 </listitem>
754 </varlistentry>
756 <varlistentry id="sql-createtable-parms-like-opt-statistics">
757 <term><literal>INCLUDING STATISTICS</literal></term>
758 <listitem>
759 <para>
760 Extended statistics are copied to the new table.
761 </para>
762 </listitem>
763 </varlistentry>
765 <varlistentry id="sql-createtable-parms-like-opt-storage">
766 <term><literal>INCLUDING STORAGE</literal></term>
767 <listitem>
768 <para>
769 <literal>STORAGE</literal> settings for the copied column
770 definitions will be copied. The default behavior is to exclude
771 <literal>STORAGE</literal> settings, resulting in the copied columns
772 in the new table having type-specific default settings. For more on
773 <literal>STORAGE</literal> settings, see <xref
774 linkend="storage-toast"/>.
775 </para>
776 </listitem>
777 </varlistentry>
779 <varlistentry id="sql-createtable-parms-like-opt-all">
780 <term><literal>INCLUDING ALL</literal></term>
781 <listitem>
782 <para>
783 <literal>INCLUDING ALL</literal> is an abbreviated form selecting
784 all the available individual options. (It could be useful to write
785 individual <literal>EXCLUDING</literal> clauses after
786 <literal>INCLUDING ALL</literal> to select all but some specific
787 options.)
788 </para>
789 </listitem>
790 </varlistentry>
791 </variablelist>
792 </para>
794 <para>
795 The <literal>LIKE</literal> clause can also be used to copy column
796 definitions from views, foreign tables, or composite types.
797 Inapplicable options (e.g., <literal>INCLUDING INDEXES</literal> from
798 a view) are ignored.
799 </para>
800 </listitem>
801 </varlistentry>
803 <varlistentry id="sql-createtable-parms-constraint">
804 <term><literal>CONSTRAINT <replaceable class="parameter">constraint_name</replaceable></literal></term>
805 <listitem>
806 <para>
807 An optional name for a column or table constraint. If the
808 constraint is violated, the constraint name is present in error messages,
809 so constraint names like <literal>col must be positive</literal> can be used
810 to communicate helpful constraint information to client applications.
811 (Double-quotes are needed to specify constraint names that contain spaces.)
812 If a constraint name is not specified, the system generates a name.
813 </para>
814 </listitem>
815 </varlistentry>
817 <varlistentry id="sql-createtable-parms-not-null">
818 <term><literal>NOT NULL</literal></term>
819 <listitem>
820 <para>
821 The column is not allowed to contain null values.
822 </para>
823 </listitem>
824 </varlistentry>
826 <varlistentry id="sql-createtable-parms-null">
827 <term><literal>NULL</literal></term>
828 <listitem>
829 <para>
830 The column is allowed to contain null values. This is the default.
831 </para>
833 <para>
834 This clause is only provided for compatibility with
835 non-standard SQL databases. Its use is discouraged in new
836 applications.
837 </para>
838 </listitem>
839 </varlistentry>
841 <varlistentry id="sql-createtable-parms-check">
842 <term><literal>CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] </literal></term>
843 <listitem>
844 <para>
845 The <literal>CHECK</literal> clause specifies an expression producing a
846 Boolean result which new or updated rows must satisfy for an
847 insert or update operation to succeed. Expressions evaluating
848 to TRUE or UNKNOWN succeed. Should any row of an insert or
849 update operation produce a FALSE result, an error exception is
850 raised and the insert or update does not alter the database. A
851 check constraint specified as a column constraint should
852 reference that column's value only, while an expression
853 appearing in a table constraint can reference multiple columns.
854 </para>
856 <para>
857 Currently, <literal>CHECK</literal> expressions cannot contain
858 subqueries nor refer to variables other than columns of the
859 current row (see <xref linkend="ddl-constraints-check-constraints"/>).
860 The system column <literal>tableoid</literal>
861 may be referenced, but not any other system column.
862 </para>
864 <para>
865 A constraint marked with <literal>NO INHERIT</literal> will not propagate to
866 child tables.
867 </para>
869 <para>
870 When a table has multiple <literal>CHECK</literal> constraints,
871 they will be tested for each row in alphabetical order by name,
872 after checking <literal>NOT NULL</literal> constraints.
873 (<productname>PostgreSQL</productname> versions before 9.5 did not honor any
874 particular firing order for <literal>CHECK</literal> constraints.)
875 </para>
876 </listitem>
877 </varlistentry>
879 <varlistentry id="sql-createtable-parms-default">
880 <term><literal>DEFAULT
881 <replaceable>default_expr</replaceable></literal></term>
882 <listitem>
883 <para>
884 The <literal>DEFAULT</literal> clause assigns a default data value for
885 the column whose column definition it appears within. The value
886 is any variable-free expression (in particular, cross-references
887 to other columns in the current table are not allowed). Subqueries
888 are not allowed either. The data type of the default expression must
889 match the data type of the column.
890 </para>
892 <para>
893 The default expression will be used in any insert operation that
894 does not specify a value for the column. If there is no default
895 for a column, then the default is null.
896 </para>
897 </listitem>
898 </varlistentry>
900 <varlistentry id="sql-createtable-parms-generated-stored">
901 <term><literal>GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) STORED</literal><indexterm><primary>generated column</primary></indexterm></term>
902 <listitem>
903 <para>
904 This clause creates the column as a <firstterm>generated
905 column</firstterm>. The column cannot be written to, and when read the
906 result of the specified expression will be returned.
907 </para>
909 <para>
910 The keyword <literal>STORED</literal> is required to signify that the
911 column will be computed on write and will be stored on disk.
912 </para>
914 <para>
915 The generation expression can refer to other columns in the table, but
916 not other generated columns. Any functions and operators used must be
917 immutable. References to other tables are not allowed.
918 </para>
919 </listitem>
920 </varlistentry>
922 <varlistentry id="sql-createtable-parms-generated-identity">
923 <term><literal>GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( <replaceable>sequence_options</replaceable> ) ]</literal></term>
924 <listitem>
925 <para>
926 This clause creates the column as an <firstterm>identity
927 column</firstterm>. It will have an implicit sequence attached to it
928 and the column in new rows will automatically have values from the
929 sequence assigned to it.
930 Such a column is implicitly <literal>NOT NULL</literal>.
931 </para>
933 <para>
934 The clauses <literal>ALWAYS</literal> and <literal>BY DEFAULT</literal>
935 determine how explicitly user-specified values are handled in
936 <command>INSERT</command> and <command>UPDATE</command> commands.
937 </para>
939 <para>
940 In an <command>INSERT</command> command, if <literal>ALWAYS</literal> is
941 selected, a user-specified value is only accepted if the
942 <command>INSERT</command> statement specifies <literal>OVERRIDING SYSTEM
943 VALUE</literal>. If <literal>BY DEFAULT</literal> is selected, then the
944 user-specified value takes precedence. See <xref linkend="sql-insert"/>
945 for details. (In the <command>COPY</command> command, user-specified
946 values are always used regardless of this setting.)
947 </para>
949 <para>
950 In an <command>UPDATE</command> command, if <literal>ALWAYS</literal> is
951 selected, any update of the column to any value other than
952 <literal>DEFAULT</literal> will be rejected. If <literal>BY
953 DEFAULT</literal> is selected, the column can be updated normally.
954 (There is no <literal>OVERRIDING</literal> clause for the
955 <command>UPDATE</command> command.)
956 </para>
958 <para>
959 The optional <replaceable>sequence_options</replaceable> clause can be
960 used to override the options of the sequence.
961 See <xref linkend="sql-createsequence"/> for details.
962 </para>
963 </listitem>
964 </varlistentry>
966 <varlistentry id="sql-createtable-parms-unique">
967 <term><literal>UNIQUE [ NULLS [ NOT ] DISTINCT ]</literal> (column constraint)</term>
968 <term><literal>UNIQUE [ NULLS [ NOT ] DISTINCT ] ( <replaceable class="parameter">column_name</replaceable> [, ... ] [, <replaceable class="parameter">column_name</replaceable> WITHOUT OVERLAPS ] )</literal>
969 <optional> <literal>INCLUDE ( <replaceable class="parameter">column_name</replaceable> [, ...])</literal> </optional> (table constraint)</term>
971 <listitem>
972 <para>
973 The <literal>UNIQUE</literal> constraint specifies that a
974 group of one or more columns of a table can contain
975 only unique values. The behavior of a unique table constraint
976 is the same as that of a unique column constraint, with the
977 additional capability to span multiple columns. The constraint
978 therefore enforces that any two rows must differ in at least one
979 of these columns.
980 </para>
982 <para>
983 If the <literal>WITHOUT OVERLAPS</literal> option is specified for the
984 last column, then that column is checked for overlaps instead of
985 equality. In that case, the other columns of the constraint will allow
986 duplicates so long as the duplicates don't overlap in the
987 <literal>WITHOUT OVERLAPS</literal> column. (This is sometimes called a
988 temporal key, if the column is a range of dates or timestamps, but
989 PostgreSQL allows ranges over any base type.) In effect, such a
990 constraint is enforced with an <literal>EXCLUDE</literal> constraint
991 rather than a <literal>UNIQUE</literal> constraint. So for example
992 <literal>UNIQUE (id, valid_at WITHOUT OVERLAPS)</literal> behaves like
993 <literal>EXCLUDE USING GIST (id WITH =, valid_at WITH
994 &amp;&amp;)</literal>. The <literal>WITHOUT OVERLAPS</literal> column
995 must have a range or multirange type. (Technically, any type is allowed
996 whose default GiST opclass includes an overlaps operator. See the
997 <literal>stratnum</literal> support function under <xref
998 linkend="gist-extensibility"/> for details.) The non-<literal>WITHOUT
999 OVERLAPS</literal> columns of the constraint can be any type that can be
1000 compared for equality in a GiST index. By default, only range types are
1001 supported, but you can use other types by adding the <xref
1002 linkend="btree-gist"/> extension (which is the expected way to use this
1003 feature).
1004 </para>
1006 <para>
1007 For the purpose of a unique constraint, null values are not
1008 considered equal, unless <literal>NULLS NOT DISTINCT</literal> is
1009 specified.
1010 </para>
1012 <para>
1013 Each unique constraint should name a set of columns that is
1014 different from the set of columns named by any other unique or
1015 primary key constraint defined for the table. (Otherwise, redundant
1016 unique constraints will be discarded.)
1017 </para>
1019 <para>
1020 When establishing a unique constraint for a multi-level partition
1021 hierarchy, all the columns in the partition key of the target
1022 partitioned table, as well as those of all its descendant partitioned
1023 tables, must be included in the constraint definition.
1024 </para>
1026 <para>
1027 Adding a unique constraint will automatically create a unique B-tree
1028 index on the column or group of columns used in the constraint. But if
1029 the constraint includes a <literal>WITHOUT OVERLAPS</literal> clause, it
1030 will use a GiST index. The created index has the same name as the unique
1031 constraint.
1032 </para>
1034 <para>
1035 The optional <literal>INCLUDE</literal> clause adds to that index
1036 one or more columns that are simply <quote>payload</quote>: uniqueness
1037 is not enforced on them, and the index cannot be searched on the basis
1038 of those columns. However they can be retrieved by an index-only scan.
1039 Note that although the constraint is not enforced on included columns,
1040 it still depends on them. Consequently, some operations on such columns
1041 (e.g., <literal>DROP COLUMN</literal>) can cause cascaded constraint and
1042 index deletion.
1043 </para>
1044 </listitem>
1045 </varlistentry>
1047 <varlistentry id="sql-createtable-parms-primary-key">
1048 <term><literal>PRIMARY KEY</literal> (column constraint)</term>
1049 <term><literal>PRIMARY KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] [, <replaceable class="parameter">column_name</replaceable> WITHOUT OVERLAPS ] )</literal>
1050 <optional> <literal>INCLUDE ( <replaceable class="parameter">column_name</replaceable> [, ...])</literal> </optional> (table constraint)</term>
1051 <listitem>
1052 <para>
1053 The <literal>PRIMARY KEY</literal> constraint specifies that a column or
1054 columns of a table can contain only unique (non-duplicate), nonnull
1055 values. Only one primary key can be specified for a table, whether as a
1056 column constraint or a table constraint.
1057 </para>
1059 <para>
1060 The primary key constraint should name a set of columns that is
1061 different from the set of columns named by any unique
1062 constraint defined for the same table. (Otherwise, the unique
1063 constraint is redundant and will be discarded.)
1064 </para>
1066 <para>
1067 <literal>PRIMARY KEY</literal> enforces the same data constraints as
1068 a combination of <literal>UNIQUE</literal> and <literal>NOT
1069 NULL</literal>. However,
1070 identifying a set of columns as the primary key also provides metadata
1071 about the design of the schema, since a primary key implies that other
1072 tables can rely on this set of columns as a unique identifier for rows.
1073 </para>
1075 <para>
1076 When placed on a partitioned table, <literal>PRIMARY KEY</literal>
1077 constraints share the restrictions previously described
1078 for <literal>UNIQUE</literal> constraints.
1079 </para>
1081 <para>
1082 As with a <literal>UNIQUE</literal> constraint, adding a
1083 <literal>PRIMARY KEY</literal> constraint will automatically create a
1084 unique B-tree index, or GiST if <literal>WITHOUT OVERLAPS</literal> was
1085 specified, on the column or group of columns used in the constraint.
1086 That index has the same name as the primary key constraint.
1087 </para>
1089 <para>
1090 The optional <literal>INCLUDE</literal> clause adds to that index
1091 one or more columns that are simply <quote>payload</quote>: uniqueness
1092 is not enforced on them, and the index cannot be searched on the basis
1093 of those columns. However they can be retrieved by an index-only scan.
1094 Note that although the constraint is not enforced on included columns,
1095 it still depends on them. Consequently, some operations on such columns
1096 (e.g., <literal>DROP COLUMN</literal>) can cause cascaded constraint and
1097 index deletion.
1098 </para>
1099 </listitem>
1100 </varlistentry>
1102 <varlistentry id="sql-createtable-exclude">
1103 <term><literal>EXCLUDE [ USING <replaceable class="parameter">index_method</replaceable> ] ( <replaceable class="parameter">exclude_element</replaceable> WITH <replaceable class="parameter">operator</replaceable> [, ... ] ) <replaceable class="parameter">index_parameters</replaceable> [ WHERE ( <replaceable class="parameter">predicate</replaceable> ) ]</literal></term>
1104 <listitem>
1105 <para>
1106 The <literal>EXCLUDE</literal> clause defines an exclusion
1107 constraint, which guarantees that if
1108 any two rows are compared on the specified column(s) or
1109 expression(s) using the specified operator(s), not all of these
1110 comparisons will return <literal>TRUE</literal>. If all of the
1111 specified operators test for equality, this is equivalent to a
1112 <literal>UNIQUE</literal> constraint, although an ordinary unique constraint
1113 will be faster. However, exclusion constraints can specify
1114 constraints that are more general than simple equality.
1115 For example, you can specify a constraint that
1116 no two rows in the table contain overlapping circles
1117 (see <xref linkend="datatype-geometric"/>) by using the
1118 <literal>&amp;&amp;</literal> operator.
1119 </para>
1121 <para>
1122 Exclusion constraints are implemented using
1123 an index that has the same name as the constraint, so each specified
1124 operator must be associated with an appropriate operator class
1125 (see <xref linkend="indexes-opclass"/>) for the index access
1126 method <replaceable>index_method</replaceable>.
1127 The operators are required to be commutative.
1128 Each <replaceable class="parameter">exclude_element</replaceable>
1129 can optionally specify an operator class and/or ordering options;
1130 these are described fully under
1131 <xref linkend="sql-createindex"/>.
1132 </para>
1134 <para>
1135 The access method must support <literal>amgettuple</literal> (see <xref
1136 linkend="indexam"/>); at present this means <acronym>GIN</acronym>
1137 cannot be used. Although it's allowed, there is little point in using
1138 B-tree or hash indexes with an exclusion constraint, because this
1139 does nothing that an ordinary unique constraint doesn't do better.
1140 So in practice the access method will always be <acronym>GiST</acronym> or
1141 <acronym>SP-GiST</acronym>.
1142 </para>
1144 <para>
1145 The <replaceable class="parameter">predicate</replaceable> allows you to specify an
1146 exclusion constraint on a subset of the table; internally this creates a
1147 partial index. Note that parentheses are required around the predicate.
1148 </para>
1149 </listitem>
1150 </varlistentry>
1152 <varlistentry id="sql-createtable-parms-references">
1153 <term><literal>REFERENCES <replaceable class="parameter">reftable</replaceable> [ ( <replaceable class="parameter">refcolumn</replaceable> ) ] [ MATCH <replaceable class="parameter">matchtype</replaceable> ] [ ON DELETE <replaceable class="parameter">referential_action</replaceable> ] [ ON UPDATE <replaceable class="parameter">referential_action</replaceable> ]</literal> (column constraint)</term>
1155 <term><literal>FOREIGN KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] [, PERIOD <replaceable class="parameter">column_name</replaceable> ] )
1156 REFERENCES <replaceable class="parameter">reftable</replaceable> [ ( <replaceable class="parameter">refcolumn</replaceable> [, ... ] [, PERIOD <replaceable class="parameter">column_name</replaceable> ] ) ]
1157 [ MATCH <replaceable class="parameter">matchtype</replaceable> ]
1158 [ ON DELETE <replaceable class="parameter">referential_action</replaceable> ]
1159 [ ON UPDATE <replaceable class="parameter">referential_action</replaceable> ]</literal>
1160 (table constraint)</term>
1162 <listitem>
1163 <para>
1164 These clauses specify a foreign key constraint, which requires
1165 that a group of one or more columns of the new table must only
1166 contain values that match values in the referenced
1167 column(s) of some row of the referenced table. If the <replaceable
1168 class="parameter">refcolumn</replaceable> list is omitted, the
1169 primary key of the <replaceable class="parameter">reftable</replaceable>
1170 is used. Otherwise, the <replaceable class="parameter">refcolumn</replaceable>
1171 list must refer to the columns of a non-deferrable unique or primary key
1172 constraint or be the columns of a non-partial unique index.
1173 </para>
1175 <para>
1176 If the last column is marked with <literal>PERIOD</literal>, it is
1177 treated in a special way. While the non-<literal>PERIOD</literal>
1178 columns are compared for equality (and there must be at least one of
1179 them), the <literal>PERIOD</literal> column is not. Instead, the
1180 constraint is considered satisfied if the referenced table has matching
1181 records (based on the non-<literal>PERIOD</literal> parts of the key)
1182 whose combined <literal>PERIOD</literal> values completely cover the
1183 referencing record's. In other words, the reference must have a
1184 referent for its entire duration. This column must be a range or
1185 multirange type. In addition, the referenced table must have a primary
1186 key or unique constraint declared with <literal>WITHOUT
1187 OVERLAPS</literal>. Finally, if one side of the foreign key uses
1188 <literal>PERIOD</literal>, the other side must too. If the <replaceable
1189 class="parameter">refcolumn</replaceable> list is omitted, the
1190 <literal>WITHOUT OVERLAPS</literal> part of the primary key is treated
1191 as if marked with <literal>PERIOD</literal>.
1192 </para>
1194 <para>
1195 The user
1196 must have <literal>REFERENCES</literal> permission on the referenced
1197 table (either the whole table, or the specific referenced columns). The
1198 addition of a foreign key constraint requires a
1199 <literal>SHARE ROW EXCLUSIVE</literal> lock on the referenced table.
1200 Note that foreign key constraints cannot be defined between temporary
1201 tables and permanent tables.
1202 </para>
1204 <para>
1205 A value inserted into the referencing column(s) is matched against the
1206 values of the referenced table and referenced columns using the
1207 given match type. There are three match types: <literal>MATCH
1208 FULL</literal>, <literal>MATCH PARTIAL</literal>, and <literal>MATCH
1209 SIMPLE</literal> (which is the default). <literal>MATCH
1210 FULL</literal> will not allow one column of a multicolumn foreign key
1211 to be null unless all foreign key columns are null; if they are all
1212 null, the row is not required to have a match in the referenced table.
1213 <literal>MATCH SIMPLE</literal> allows any of the foreign key columns
1214 to be null; if any of them are null, the row is not required to have a
1215 match in the referenced table.
1216 <literal>MATCH PARTIAL</literal> is not yet implemented.
1217 (Of course, <literal>NOT NULL</literal> constraints can be applied to the
1218 referencing column(s) to prevent these cases from arising.)
1219 </para>
1221 <para>
1222 In addition, when the data in the referenced columns is changed,
1223 certain actions are performed on the data in this table's
1224 columns. The <literal>ON DELETE</literal> clause specifies the
1225 action to perform when a referenced row in the referenced table is
1226 being deleted. Likewise, the <literal>ON UPDATE</literal>
1227 clause specifies the action to perform when a referenced column
1228 in the referenced table is being updated to a new value. If the
1229 row is updated, but the referenced column is not actually
1230 changed, no action is done. Referential actions other than the
1231 <literal>NO ACTION</literal> check cannot be deferred, even if
1232 the constraint is declared deferrable. There are the following possible
1233 actions for each clause:
1235 <variablelist>
1236 <varlistentry id="sql-createtable-parms-references-refact-no-action">
1237 <term><literal>NO ACTION</literal></term>
1238 <listitem>
1239 <para>
1240 Produce an error indicating that the deletion or update
1241 would create a foreign key constraint violation.
1242 If the constraint is deferred, this
1243 error will be produced at constraint check time if there still
1244 exist any referencing rows. This is the default action.
1245 </para>
1246 </listitem>
1247 </varlistentry>
1249 <varlistentry id="sql-createtable-parms-references-refact-restrict">
1250 <term><literal>RESTRICT</literal></term>
1251 <listitem>
1252 <para>
1253 Produce an error indicating that the deletion or update
1254 would create a foreign key constraint violation.
1255 This is the same as <literal>NO ACTION</literal> except that
1256 the check is not deferrable.
1257 </para>
1258 </listitem>
1259 </varlistentry>
1261 <varlistentry id="sql-createtable-parms-references-refact-cascade">
1262 <term><literal>CASCADE</literal></term>
1263 <listitem>
1264 <para>
1265 Delete any rows referencing the deleted row, or update the
1266 values of the referencing column(s) to the new values of the
1267 referenced columns, respectively.
1268 </para>
1270 <para>
1271 In a temporal foreign key, this option is not supported.
1272 </para>
1273 </listitem>
1274 </varlistentry>
1276 <varlistentry id="sql-createtable-parms-references-refact-set-null">
1277 <term><literal>SET NULL [ ( <replaceable>column_name</replaceable> [, ... ] ) ]</literal></term>
1278 <listitem>
1279 <para>
1280 Set all of the referencing columns, or a specified subset of the
1281 referencing columns, to null. A subset of columns can only be
1282 specified for <literal>ON DELETE</literal> actions.
1283 </para>
1285 <para>
1286 In a temporal foreign key, this option is not supported.
1287 </para>
1288 </listitem>
1289 </varlistentry>
1291 <varlistentry id="sql-createtable-parms-references-refact-set-default">
1292 <term><literal>SET DEFAULT [ ( <replaceable>column_name</replaceable> [, ... ] ) ]</literal></term>
1293 <listitem>
1294 <para>
1295 Set all of the referencing columns, or a specified subset of the
1296 referencing columns, to their default values. A subset of columns
1297 can only be specified for <literal>ON DELETE</literal> actions.
1298 (There must be a row in the referenced table matching the default
1299 values, if they are not null, or the operation will fail.)
1300 </para>
1302 <para>
1303 In a temporal foreign key, this option is not supported.
1304 </para>
1305 </listitem>
1306 </varlistentry>
1307 </variablelist>
1308 </para>
1310 <para>
1311 If the referenced column(s) are changed frequently, it might be wise to
1312 add an index to the referencing column(s) so that referential actions
1313 associated with the foreign key constraint can be performed more
1314 efficiently.
1315 </para>
1316 </listitem>
1317 </varlistentry>
1319 <varlistentry id="sql-createtable-parms-deferrable">
1320 <term><literal>DEFERRABLE</literal></term>
1321 <term><literal>NOT DEFERRABLE</literal></term>
1322 <listitem>
1323 <para>
1324 This controls whether the constraint can be deferred. A
1325 constraint that is not deferrable will be checked immediately
1326 after every command. Checking of constraints that are
1327 deferrable can be postponed until the end of the transaction
1328 (using the <link linkend="sql-set-constraints"><command>SET CONSTRAINTS</command></link> command).
1329 <literal>NOT DEFERRABLE</literal> is the default.
1330 Currently, only <literal>UNIQUE</literal>, <literal>PRIMARY KEY</literal>,
1331 <literal>EXCLUDE</literal>, and
1332 <literal>REFERENCES</literal> (foreign key) constraints accept this
1333 clause. <literal>NOT NULL</literal> and <literal>CHECK</literal> constraints are not
1334 deferrable. Note that deferrable constraints cannot be used as
1335 conflict arbitrators in an <command>INSERT</command> statement that
1336 includes an <literal>ON CONFLICT DO UPDATE</literal> clause.
1337 </para>
1338 </listitem>
1339 </varlistentry>
1341 <varlistentry id="sql-createtable-parms-initially">
1342 <term><literal>INITIALLY IMMEDIATE</literal></term>
1343 <term><literal>INITIALLY DEFERRED</literal></term>
1344 <listitem>
1345 <para>
1346 If a constraint is deferrable, this clause specifies the default
1347 time to check the constraint. If the constraint is
1348 <literal>INITIALLY IMMEDIATE</literal>, it is checked after each
1349 statement. This is the default. If the constraint is
1350 <literal>INITIALLY DEFERRED</literal>, it is checked only at the
1351 end of the transaction. The constraint check time can be
1352 altered with the <link linkend="sql-set-constraints"><command>SET CONSTRAINTS</command></link> command.
1353 </para>
1354 </listitem>
1355 </varlistentry>
1357 <varlistentry id="sql-createtable-method">
1358 <term><literal>USING <replaceable class="parameter">method</replaceable></literal></term>
1359 <listitem>
1360 <para>
1361 This optional clause specifies the table access method to use to store
1362 the contents for the new table; the method needs be an access method of
1363 type <literal>TABLE</literal>. See <xref linkend="tableam"/> for more
1364 information. If this option is not specified, the default table access
1365 method is chosen for the new table. See <xref
1366 linkend="guc-default-table-access-method"/> for more information.
1367 </para>
1368 <para>
1369 When creating a partition, the table access method is the access method
1370 of its partitioned table, if set.
1371 </para>
1372 </listitem>
1373 </varlistentry>
1375 <varlistentry id="sql-createtable-parms-with">
1376 <term><literal>WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] )</literal></term>
1377 <listitem>
1378 <para>
1379 This clause specifies optional storage parameters for a table or index;
1380 see <xref linkend="sql-createtable-storage-parameters"/> below for more
1381 information. For backward-compatibility the <literal>WITH</literal>
1382 clause for a table can also include <literal>OIDS=FALSE</literal> to
1383 specify that rows of the new table should not contain OIDs (object
1384 identifiers), <literal>OIDS=TRUE</literal> is not supported anymore.
1385 </para>
1386 </listitem>
1387 </varlistentry>
1389 <varlistentry id="sql-createtable-parms-without-oids">
1390 <term><literal>WITHOUT OIDS</literal></term>
1391 <listitem>
1392 <para>
1393 This is backward-compatible syntax for declaring a table
1394 <literal>WITHOUT OIDS</literal>, creating a table <literal>WITH
1395 OIDS</literal> is not supported anymore.
1396 </para>
1397 </listitem>
1398 </varlistentry>
1400 <varlistentry id="sql-createtable-parms-on-commit">
1401 <term><literal>ON COMMIT</literal></term>
1402 <listitem>
1403 <para>
1404 The behavior of temporary tables at the end of a transaction
1405 block can be controlled using <literal>ON COMMIT</literal>.
1406 The three options are:
1408 <variablelist>
1409 <varlistentry id="sql-createtable-parms-on-commit-preserve-rows">
1410 <term><literal>PRESERVE ROWS</literal></term>
1411 <listitem>
1412 <para>
1413 No special action is taken at the ends of transactions.
1414 This is the default behavior.
1415 </para>
1416 </listitem>
1417 </varlistentry>
1419 <varlistentry id="sql-createtable-parms-on-commit-delete-rows">
1420 <term><literal>DELETE ROWS</literal></term>
1421 <listitem>
1422 <para>
1423 All rows in the temporary table will be deleted at the end
1424 of each transaction block. Essentially, an automatic <link
1425 linkend="sql-truncate"><command>TRUNCATE</command></link> is done
1426 at each commit. When used on a partitioned table, this
1427 is not cascaded to its partitions.
1428 </para>
1429 </listitem>
1430 </varlistentry>
1432 <varlistentry id="sql-createtable-parms-on-commit-drop">
1433 <term><literal>DROP</literal></term>
1434 <listitem>
1435 <para>
1436 The temporary table will be dropped at the end of the current
1437 transaction block. When used on a partitioned table, this action
1438 drops its partitions and when used on tables with inheritance
1439 children, it drops the dependent children.
1440 </para>
1441 </listitem>
1442 </varlistentry>
1443 </variablelist></para>
1444 </listitem>
1445 </varlistentry>
1447 <varlistentry id="sql-createtable-tablespace">
1448 <term><literal>TABLESPACE <replaceable class="parameter">tablespace_name</replaceable></literal></term>
1449 <listitem>
1450 <para>
1451 The <replaceable class="parameter">tablespace_name</replaceable> is the name
1452 of the tablespace in which the new table is to be created.
1453 If not specified,
1454 <xref linkend="guc-default-tablespace"/> is consulted, or
1455 <xref linkend="guc-temp-tablespaces"/> if the table is temporary. For
1456 partitioned tables, since no storage is required for the table itself,
1457 the tablespace specified overrides <literal>default_tablespace</literal>
1458 as the default tablespace to use for any newly created partitions when no
1459 other tablespace is explicitly specified.
1460 </para>
1461 </listitem>
1462 </varlistentry>
1464 <varlistentry id="sql-createtable-parms-using-index-tablespace">
1465 <term><literal>USING INDEX TABLESPACE <replaceable class="parameter">tablespace_name</replaceable></literal></term>
1466 <listitem>
1467 <para>
1468 This clause allows selection of the tablespace in which the index
1469 associated with a <literal>UNIQUE</literal>, <literal>PRIMARY
1470 KEY</literal>, or <literal>EXCLUDE</literal> constraint will be created.
1471 If not specified,
1472 <xref linkend="guc-default-tablespace"/> is consulted, or
1473 <xref linkend="guc-temp-tablespaces"/> if the table is temporary.
1474 </para>
1475 </listitem>
1476 </varlistentry>
1478 </variablelist>
1480 <refsect2 id="sql-createtable-storage-parameters" xreflabel="Storage Parameters">
1481 <title>Storage Parameters</title>
1483 <indexterm zone="sql-createtable-storage-parameters">
1484 <primary>storage parameters</primary>
1485 </indexterm>
1487 <para>
1488 The <literal>WITH</literal> clause can specify <firstterm>storage parameters</firstterm>
1489 for tables, and for indexes associated with a <literal>UNIQUE</literal>,
1490 <literal>PRIMARY KEY</literal>, or <literal>EXCLUDE</literal> constraint.
1491 Storage parameters for
1492 indexes are documented in <xref linkend="sql-createindex"/>.
1493 The storage parameters currently
1494 available for tables are listed below. For many of these parameters, as
1495 shown, there is an additional parameter with the same name prefixed with
1496 <literal>toast.</literal>, which controls the behavior of the
1497 table's secondary <acronym>TOAST</acronym> table, if any
1498 (see <xref linkend="storage-toast"/> for more information about TOAST).
1499 If a table parameter value is set and the
1500 equivalent <literal>toast.</literal> parameter is not, the TOAST table
1501 will use the table's parameter value.
1502 Specifying these parameters for partitioned tables is not supported,
1503 but you may specify them for individual leaf partitions.
1504 </para>
1506 <variablelist>
1508 <varlistentry id="reloption-fillfactor" xreflabel="fillfactor">
1509 <term><varname>fillfactor</varname> (<type>integer</type>)
1510 <indexterm>
1511 <primary><varname>fillfactor</varname> storage parameter</primary>
1512 </indexterm>
1513 </term>
1514 <listitem>
1515 <para>
1516 The fillfactor for a table is a percentage between 10 and 100.
1517 100 (complete packing) is the default. When a smaller fillfactor
1518 is specified, <command>INSERT</command> operations pack table pages only
1519 to the indicated percentage; the remaining space on each page is
1520 reserved for updating rows on that page. This gives <command>UPDATE</command>
1521 a chance to place the updated copy of a row on the same page as the
1522 original, which is more efficient than placing it on a different
1523 page, and makes <link linkend="storage-hot">heap-only tuple
1524 updates</link> more likely.
1525 For a table whose entries are never updated, complete packing is the
1526 best choice, but in heavily updated tables smaller fillfactors are
1527 appropriate. This parameter cannot be set for TOAST tables.
1528 </para>
1529 </listitem>
1530 </varlistentry>
1532 <varlistentry id="reloption-toast-tuple-target" xreflabel="toast_tuple_target">
1533 <term><literal>toast_tuple_target</literal> (<type>integer</type>)
1534 <indexterm>
1535 <primary><varname>toast_tuple_target</varname> storage parameter</primary>
1536 </indexterm>
1537 </term>
1538 <listitem>
1539 <para>
1540 The toast_tuple_target specifies the minimum tuple length required before
1541 we try to compress and/or move long column values into TOAST tables, and
1542 is also the target length we try to reduce the length below once toasting
1543 begins. This affects columns marked as External (for move),
1544 Main (for compression), or Extended (for both) and applies only to new
1545 tuples. There is no effect on existing rows.
1546 By default this parameter is set to allow at least 4 tuples per block,
1547 which with the default block size will be 2040 bytes. Valid values are
1548 between 128 bytes and the (block size - header), by default 8160 bytes.
1549 Changing this value may not be useful for very short or very long rows.
1550 Note that the default setting is often close to optimal, and
1551 it is possible that setting this parameter could have negative
1552 effects in some cases.
1553 This parameter cannot be set for TOAST tables.
1554 </para>
1555 </listitem>
1556 </varlistentry>
1558 <varlistentry id="reloption-parallel-workers" xreflabel="parallel_workers">
1559 <term><literal>parallel_workers</literal> (<type>integer</type>)
1560 <indexterm>
1561 <primary><varname>parallel_workers</varname> storage parameter</primary>
1562 </indexterm>
1563 </term>
1564 <listitem>
1565 <para>
1566 This sets the number of workers that should be used to assist a parallel
1567 scan of this table. If not set, the system will determine a value based
1568 on the relation size. The actual number of workers chosen by the planner
1569 or by utility statements that use parallel scans may be less, for example
1570 due to the setting of <xref linkend="guc-max-worker-processes"/>.
1571 </para>
1572 </listitem>
1573 </varlistentry>
1575 <varlistentry id="reloption-autovacuum-enabled" xreflabel="autovacuum_enabled">
1576 <term><literal>autovacuum_enabled</literal>, <literal>toast.autovacuum_enabled</literal> (<type>boolean</type>)
1577 <indexterm>
1578 <primary><varname>autovacuum_enabled</varname> storage parameter</primary>
1579 </indexterm>
1580 </term>
1581 <listitem>
1582 <para>
1583 Enables or disables the autovacuum daemon for a particular table.
1584 If true, the autovacuum daemon will perform automatic <command>VACUUM</command>
1585 and/or <command>ANALYZE</command> operations on this table following the rules
1586 discussed in <xref linkend="autovacuum"/>.
1587 If false, this table will not be autovacuumed, except to prevent
1588 transaction ID wraparound. See <xref linkend="vacuum-for-wraparound"/> for
1589 more about wraparound prevention.
1590 Note that the autovacuum daemon does not run at all (except to prevent
1591 transaction ID wraparound) if the <xref linkend="guc-autovacuum"/>
1592 parameter is false; setting individual tables' storage parameters does
1593 not override that. Therefore there is seldom much point in explicitly
1594 setting this storage parameter to <literal>true</literal>, only
1595 to <literal>false</literal>.
1596 </para>
1597 </listitem>
1598 </varlistentry>
1600 <varlistentry id="reloption-vacuum-index-cleanup" xreflabel="vacuum_index_cleanup">
1601 <term><literal>vacuum_index_cleanup</literal>, <literal>toast.vacuum_index_cleanup</literal> (<type>enum</type>)
1602 <indexterm>
1603 <primary><varname>vacuum_index_cleanup</varname> storage parameter</primary>
1604 </indexterm>
1605 </term>
1606 <listitem>
1607 <para>
1608 Forces or disables index cleanup when <command>VACUUM</command>
1609 is run on this table. The default value is
1610 <literal>AUTO</literal>. With <literal>OFF</literal>, index
1611 cleanup is disabled, with <literal>ON</literal> it is enabled,
1612 and with <literal>AUTO</literal> a decision is made dynamically,
1613 each time <command>VACUUM</command> runs. The dynamic behavior
1614 allows <command>VACUUM</command> to avoid needlessly scanning
1615 indexes to remove very few dead tuples. Forcibly disabling all
1616 index cleanup can speed up <command>VACUUM</command> very
1617 significantly, but may also lead to severely bloated indexes if
1618 table modifications are frequent. The
1619 <literal>INDEX_CLEANUP</literal> parameter of <link
1620 linkend="sql-vacuum"><command>VACUUM</command></link>, if
1621 specified, overrides the value of this option.
1622 </para>
1623 </listitem>
1624 </varlistentry>
1626 <varlistentry id="reloption-vacuum-truncate" xreflabel="vacuum_truncate">
1627 <term><literal>vacuum_truncate</literal>, <literal>toast.vacuum_truncate</literal> (<type>boolean</type>)
1628 <indexterm>
1629 <primary><varname>vacuum_truncate</varname> storage parameter</primary>
1630 </indexterm>
1631 </term>
1632 <listitem>
1633 <para>
1634 Enables or disables vacuum to try to truncate off any empty pages
1635 at the end of this table. The default value is <literal>true</literal>.
1636 If <literal>true</literal>, <command>VACUUM</command> and
1637 autovacuum do the truncation and the disk space for
1638 the truncated pages is returned to the operating system.
1639 Note that the truncation requires <literal>ACCESS EXCLUSIVE</literal>
1640 lock on the table. The <literal>TRUNCATE</literal> parameter
1641 of <link linkend="sql-vacuum"><command>VACUUM</command></link>, if specified, overrides the value
1642 of this option.
1643 </para>
1644 </listitem>
1645 </varlistentry>
1647 <varlistentry id="reloption-autovacuum-vacuum-threshold" xreflabel="autovacuum_vacuum_threshold">
1648 <term><literal>autovacuum_vacuum_threshold</literal>, <literal>toast.autovacuum_vacuum_threshold</literal> (<type>integer</type>)
1649 <indexterm>
1650 <primary><varname>autovacuum_vacuum_threshold</varname></primary>
1651 <secondary>storage parameter</secondary>
1652 </indexterm>
1653 </term>
1654 <listitem>
1655 <para>
1656 Per-table value for <xref linkend="guc-autovacuum-vacuum-threshold"/>
1657 parameter.
1658 </para>
1659 </listitem>
1660 </varlistentry>
1662 <varlistentry id="reloption-autovacuum-vacuum-scale-factor" xreflabel="autovacuum_vacuum_scale_factor">
1663 <term><literal>autovacuum_vacuum_scale_factor</literal>, <literal>toast.autovacuum_vacuum_scale_factor</literal> (<type>floating point</type>)
1664 <indexterm>
1665 <primary><varname>autovacuum_vacuum_scale_factor</varname> </primary>
1666 <secondary>storage parameter</secondary>
1667 </indexterm>
1668 </term>
1669 <listitem>
1670 <para>
1671 Per-table value for <xref linkend="guc-autovacuum-vacuum-scale-factor"/>
1672 parameter.
1673 </para>
1674 </listitem>
1675 </varlistentry>
1677 <varlistentry id="reloption-autovacuum-vacuum-insert-threshold" xreflabel="autovacuum_vacuum_insert_threshold">
1678 <term><literal>autovacuum_vacuum_insert_threshold</literal>, <literal>toast.autovacuum_vacuum_insert_threshold</literal> (<type>integer</type>)
1679 <indexterm>
1680 <primary><varname>autovacuum_vacuum_insert_threshold</varname></primary>
1681 <secondary>storage parameter</secondary>
1682 </indexterm>
1683 </term>
1684 <listitem>
1685 <para>
1686 Per-table value for <xref linkend="guc-autovacuum-vacuum-insert-threshold"/>
1687 parameter. The special value of -1 may be used to disable insert vacuums on the table.
1688 </para>
1689 </listitem>
1690 </varlistentry>
1692 <varlistentry id="reloption-autovacuum-vacuum-insert-scale-factor" xreflabel="autovacuum_vacuum_insert_scale_factor">
1693 <term><literal>autovacuum_vacuum_insert_scale_factor</literal>, <literal>toast.autovacuum_vacuum_insert_scale_factor</literal> (<type>floating point</type>)
1694 <indexterm>
1695 <primary><varname>autovacuum_vacuum_insert_scale_factor</varname> </primary>
1696 <secondary>storage parameter</secondary>
1697 </indexterm>
1698 </term>
1699 <listitem>
1700 <para>
1701 Per-table value for <xref linkend="guc-autovacuum-vacuum-insert-scale-factor"/>
1702 parameter.
1703 </para>
1704 </listitem>
1705 </varlistentry>
1707 <varlistentry id="reloption-autovacuum-analyze-threshold" xreflabel="autovacuum_analyze_threshold">
1708 <term><literal>autovacuum_analyze_threshold</literal> (<type>integer</type>)
1709 <indexterm>
1710 <primary><varname>autovacuum_analyze_threshold</varname></primary>
1711 <secondary>storage parameter</secondary>
1712 </indexterm>
1713 </term>
1714 <listitem>
1715 <para>
1716 Per-table value for <xref linkend="guc-autovacuum-analyze-threshold"/>
1717 parameter.
1718 </para>
1719 </listitem>
1720 </varlistentry>
1722 <varlistentry id="reloption-autovacuum-analyze-scale-factor" xreflabel="autovacuum_analyze_scale_factor">
1723 <term><literal>autovacuum_analyze_scale_factor</literal> (<type>floating point</type>)
1724 <indexterm>
1725 <primary><varname>autovacuum_analyze_scale_factor</varname></primary>
1726 <secondary>storage parameter</secondary>
1727 </indexterm>
1728 </term>
1729 <listitem>
1730 <para>
1731 Per-table value for <xref linkend="guc-autovacuum-analyze-scale-factor"/>
1732 parameter.
1733 </para>
1734 </listitem>
1735 </varlistentry>
1737 <varlistentry id="reloption-autovacuum-vacuum-cost-delay" xreflabel="autovacuum_vacuum_cost_delay">
1738 <term><literal>autovacuum_vacuum_cost_delay</literal>, <literal>toast.autovacuum_vacuum_cost_delay</literal> (<type>floating point</type>)
1739 <indexterm>
1740 <primary><varname>autovacuum_vacuum_cost_delay</varname></primary>
1741 <secondary>storage parameter</secondary>
1742 </indexterm>
1743 </term>
1744 <listitem>
1745 <para>
1746 Per-table value for <xref linkend="guc-autovacuum-vacuum-cost-delay"/>
1747 parameter.
1748 </para>
1749 </listitem>
1750 </varlistentry>
1752 <varlistentry id="reloption-autovacuum-vacuum-cost-limit" xreflabel="autovacuum_vacuum_cost_limit">
1753 <term><literal>autovacuum_vacuum_cost_limit</literal>, <literal>toast.autovacuum_vacuum_cost_limit</literal> (<type>integer</type>)
1754 <indexterm>
1755 <primary><varname>autovacuum_vacuum_cost_limit</varname></primary>
1756 <secondary>storage parameter</secondary>
1757 </indexterm>
1758 </term>
1759 <listitem>
1760 <para>
1761 Per-table value for <xref linkend="guc-autovacuum-vacuum-cost-limit"/>
1762 parameter.
1763 </para>
1764 </listitem>
1765 </varlistentry>
1767 <varlistentry id="reloption-autovacuum-freeze-min-age" xreflabel="autovacuum_freeze_min_age">
1768 <term><literal>autovacuum_freeze_min_age</literal>, <literal>toast.autovacuum_freeze_min_age</literal> (<type>integer</type>)
1769 <indexterm>
1770 <primary><varname>autovacuum_freeze_min_age</varname> storage parameter</primary>
1771 </indexterm>
1772 </term>
1773 <listitem>
1774 <para>
1775 Per-table value for <xref linkend="guc-vacuum-freeze-min-age"/>
1776 parameter. Note that autovacuum will ignore
1777 per-table <literal>autovacuum_freeze_min_age</literal> parameters that are
1778 larger than half the
1779 system-wide <xref linkend="guc-autovacuum-freeze-max-age"/> setting.
1780 </para>
1781 </listitem>
1782 </varlistentry>
1784 <varlistentry id="reloption-autovacuum-freeze-max-age" xreflabel="autovacuum_freeze_max_age">
1785 <term><literal>autovacuum_freeze_max_age</literal>, <literal>toast.autovacuum_freeze_max_age</literal> (<type>integer</type>)
1786 <indexterm>
1787 <primary><varname>autovacuum_freeze_max_age</varname></primary>
1788 <secondary>storage parameter</secondary>
1789 </indexterm>
1790 </term>
1791 <listitem>
1792 <para>
1793 Per-table value for <xref linkend="guc-autovacuum-freeze-max-age"/>
1794 parameter. Note that autovacuum will ignore
1795 per-table <literal>autovacuum_freeze_max_age</literal> parameters that are
1796 larger than the system-wide setting (it can only be set smaller).
1797 </para>
1798 </listitem>
1799 </varlistentry>
1801 <varlistentry id="reloption-autovacuum-freeze-table-age" xreflabel="autovacuum_freeze_table_age">
1802 <term><literal>autovacuum_freeze_table_age</literal>, <literal>toast.autovacuum_freeze_table_age</literal> (<type>integer</type>)
1803 <indexterm>
1804 <primary><varname>autovacuum_freeze_table_age</varname> storage parameter</primary>
1805 </indexterm>
1806 </term>
1807 <listitem>
1808 <para>
1809 Per-table value for <xref linkend="guc-vacuum-freeze-table-age"/>
1810 parameter.
1811 </para>
1812 </listitem>
1813 </varlistentry>
1815 <varlistentry id="reloption-autovacuum-multixact-freeze-min-age" xreflabel="autovacuum_multixact_freeze_min_age">
1816 <term><literal>autovacuum_multixact_freeze_min_age</literal>, <literal>toast.autovacuum_multixact_freeze_min_age</literal> (<type>integer</type>)
1817 <indexterm>
1818 <primary><varname>autovacuum_multixact_freeze_min_age</varname> storage parameter</primary>
1819 </indexterm>
1820 </term>
1821 <listitem>
1822 <para>
1823 Per-table value for <xref linkend="guc-vacuum-multixact-freeze-min-age"/>
1824 parameter. Note that autovacuum will ignore
1825 per-table <literal>autovacuum_multixact_freeze_min_age</literal> parameters
1826 that are larger than half the
1827 system-wide <xref linkend="guc-autovacuum-multixact-freeze-max-age"/>
1828 setting.
1829 </para>
1830 </listitem>
1831 </varlistentry>
1833 <varlistentry id="reloption-autovacuum-multixact-freeze-max-age" xreflabel="autovacuum_multixact_freeze_max_age">
1834 <term><literal>autovacuum_multixact_freeze_max_age</literal>, <literal>toast.autovacuum_multixact_freeze_max_age</literal> (<type>integer</type>)
1835 <indexterm>
1836 <primary><varname>autovacuum_multixact_freeze_max_age</varname></primary>
1837 <secondary>storage parameter</secondary>
1838 </indexterm>
1839 </term>
1840 <listitem>
1841 <para>
1842 Per-table value
1843 for <xref linkend="guc-autovacuum-multixact-freeze-max-age"/> parameter.
1844 Note that autovacuum will ignore
1845 per-table <literal>autovacuum_multixact_freeze_max_age</literal> parameters
1846 that are larger than the system-wide setting (it can only be set
1847 smaller).
1848 </para>
1849 </listitem>
1850 </varlistentry>
1852 <varlistentry id="reloption-autovacuum-multixact-freeze-table-age" xreflabel="autovacuum_multixact_freeze_table_age">
1853 <term><literal>autovacuum_multixact_freeze_table_age</literal>, <literal>toast.autovacuum_multixact_freeze_table_age</literal> (<type>integer</type>)
1854 <indexterm>
1855 <primary><varname>autovacuum_multixact_freeze_table_age</varname> storage parameter</primary>
1856 </indexterm>
1857 </term>
1858 <listitem>
1859 <para>
1860 Per-table value
1861 for <xref linkend="guc-vacuum-multixact-freeze-table-age"/> parameter.
1862 </para>
1863 </listitem>
1864 </varlistentry>
1866 <varlistentry id="reloption-log-autovacuum-min-duration" xreflabel="log_autovacuum_min_duration">
1867 <term><literal>log_autovacuum_min_duration</literal>, <literal>toast.log_autovacuum_min_duration</literal> (<type>integer</type>)
1868 <indexterm>
1869 <primary><varname>log_autovacuum_min_duration</varname></primary>
1870 <secondary>storage parameter</secondary>
1871 </indexterm>
1872 </term>
1873 <listitem>
1874 <para>
1875 Per-table value for <xref linkend="guc-log-autovacuum-min-duration"/>
1876 parameter.
1877 </para>
1878 </listitem>
1879 </varlistentry>
1881 <varlistentry id="reloption-user-catalog-table" xreflabel="user_catalog_table">
1882 <term><literal>user_catalog_table</literal> (<type>boolean</type>)
1883 <indexterm>
1884 <primary><varname>user_catalog_table</varname> storage parameter</primary>
1885 </indexterm>
1886 </term>
1887 <listitem>
1888 <para>
1889 Declare the table as an additional catalog table for purposes of
1890 logical replication. See
1891 <xref linkend="logicaldecoding-capabilities"/> for details.
1892 This parameter cannot be set for TOAST tables.
1893 </para>
1894 </listitem>
1895 </varlistentry>
1897 </variablelist>
1899 </refsect2>
1900 </refsect1>
1902 <refsect1 id="sql-createtable-notes">
1903 <title>Notes</title>
1904 <para>
1905 <productname>PostgreSQL</productname> automatically creates an
1906 index for each unique constraint and primary key constraint to
1907 enforce uniqueness. Thus, it is not necessary to create an
1908 index explicitly for primary key columns. (See <xref
1909 linkend="sql-createindex"/> for more information.)
1910 </para>
1912 <para>
1913 Unique constraints and primary keys are not inherited in the
1914 current implementation. This makes the combination of
1915 inheritance and unique constraints rather dysfunctional.
1916 </para>
1918 <para>
1919 A table cannot have more than 1600 columns. (In practice, the
1920 effective limit is usually lower because of tuple-length constraints.)
1921 </para>
1923 </refsect1>
1926 <refsect1 id="sql-createtable-examples">
1927 <title>Examples</title>
1929 <para>
1930 Create table <structname>films</structname> and table
1931 <structname>distributors</structname>:
1933 <programlisting>
1934 CREATE TABLE films (
1935 code char(5) CONSTRAINT firstkey PRIMARY KEY,
1936 title varchar(40) NOT NULL,
1937 did integer NOT NULL,
1938 date_prod date,
1939 kind varchar(10),
1940 len interval hour to minute
1943 CREATE TABLE distributors (
1944 did integer PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY,
1945 name varchar(40) NOT NULL CHECK (name &lt;&gt; '')
1947 </programlisting>
1948 </para>
1950 <para>
1951 Create a table with a 2-dimensional array:
1953 <programlisting>
1954 CREATE TABLE array_int (
1955 vector int[][]
1957 </programlisting>
1958 </para>
1960 <para>
1961 Define a unique table constraint for the table
1962 <literal>films</literal>. Unique table constraints can be defined
1963 on one or more columns of the table:
1965 <programlisting>
1966 CREATE TABLE films (
1967 code char(5),
1968 title varchar(40),
1969 did integer,
1970 date_prod date,
1971 kind varchar(10),
1972 len interval hour to minute,
1973 CONSTRAINT production UNIQUE(date_prod)
1975 </programlisting>
1976 </para>
1978 <para>
1979 Define a check column constraint:
1981 <programlisting>
1982 CREATE TABLE distributors (
1983 did integer CHECK (did &gt; 100),
1984 name varchar(40)
1986 </programlisting>
1987 </para>
1989 <para>
1990 Define a check table constraint:
1992 <programlisting>
1993 CREATE TABLE distributors (
1994 did integer,
1995 name varchar(40),
1996 CONSTRAINT con1 CHECK (did &gt; 100 AND name &lt;&gt; '')
1998 </programlisting>
1999 </para>
2001 <para>
2002 Define a primary key table constraint for the table
2003 <structname>films</structname>:
2005 <programlisting>
2006 CREATE TABLE films (
2007 code char(5),
2008 title varchar(40),
2009 did integer,
2010 date_prod date,
2011 kind varchar(10),
2012 len interval hour to minute,
2013 CONSTRAINT code_title PRIMARY KEY(code,title)
2015 </programlisting>
2016 </para>
2018 <para>
2019 Define a primary key constraint for table
2020 <structname>distributors</structname>. The following two examples are
2021 equivalent, the first using the table constraint syntax, the second
2022 the column constraint syntax:
2024 <programlisting>
2025 CREATE TABLE distributors (
2026 did integer,
2027 name varchar(40),
2028 PRIMARY KEY(did)
2031 CREATE TABLE distributors (
2032 did integer PRIMARY KEY,
2033 name varchar(40)
2035 </programlisting>
2036 </para>
2038 <para>
2039 Assign a literal constant default value for the column
2040 <literal>name</literal>, arrange for the default value of column
2041 <literal>did</literal> to be generated by selecting the next value
2042 of a sequence object, and make the default value of
2043 <literal>modtime</literal> be the time at which the row is
2044 inserted:
2046 <programlisting>
2047 CREATE TABLE distributors (
2048 name varchar(40) DEFAULT 'Luso Films',
2049 did integer DEFAULT nextval('distributors_serial'),
2050 modtime timestamp DEFAULT current_timestamp
2052 </programlisting>
2053 </para>
2055 <para>
2056 Define two <literal>NOT NULL</literal> column constraints on the table
2057 <classname>distributors</classname>, one of which is explicitly
2058 given a name:
2060 <programlisting>
2061 CREATE TABLE distributors (
2062 did integer CONSTRAINT no_null NOT NULL,
2063 name varchar(40) NOT NULL
2065 </programlisting>
2066 </para>
2068 <para>
2069 Define a unique constraint for the <literal>name</literal> column:
2071 <programlisting>
2072 CREATE TABLE distributors (
2073 did integer,
2074 name varchar(40) UNIQUE
2076 </programlisting>
2078 The same, specified as a table constraint:
2080 <programlisting>
2081 CREATE TABLE distributors (
2082 did integer,
2083 name varchar(40),
2084 UNIQUE(name)
2086 </programlisting>
2087 </para>
2089 <para>
2090 Create the same table, specifying 70% fill factor for both the table
2091 and its unique index:
2093 <programlisting>
2094 CREATE TABLE distributors (
2095 did integer,
2096 name varchar(40),
2097 UNIQUE(name) WITH (fillfactor=70)
2099 WITH (fillfactor=70);
2100 </programlisting>
2101 </para>
2103 <para>
2104 Create table <structname>circles</structname> with an exclusion
2105 constraint that prevents any two circles from overlapping:
2107 <programlisting>
2108 CREATE TABLE circles (
2109 c circle,
2110 EXCLUDE USING gist (c WITH &amp;&amp;)
2112 </programlisting>
2113 </para>
2115 <para>
2116 Create table <structname>cinemas</structname> in tablespace <structname>diskvol1</structname>:
2118 <programlisting>
2119 CREATE TABLE cinemas (
2120 id serial,
2121 name text,
2122 location text
2123 ) TABLESPACE diskvol1;
2124 </programlisting>
2125 </para>
2127 <para>
2128 Create a composite type and a typed table:
2129 <programlisting>
2130 CREATE TYPE employee_type AS (name text, salary numeric);
2132 CREATE TABLE employees OF employee_type (
2133 PRIMARY KEY (name),
2134 salary WITH OPTIONS DEFAULT 1000
2136 </programlisting></para>
2138 <para>
2139 Create a range partitioned table:
2140 <programlisting>
2141 CREATE TABLE measurement (
2142 logdate date not null,
2143 peaktemp int,
2144 unitsales int
2145 ) PARTITION BY RANGE (logdate);
2146 </programlisting></para>
2148 <para>
2149 Create a range partitioned table with multiple columns in the partition key:
2150 <programlisting>
2151 CREATE TABLE measurement_year_month (
2152 logdate date not null,
2153 peaktemp int,
2154 unitsales int
2155 ) PARTITION BY RANGE (EXTRACT(YEAR FROM logdate), EXTRACT(MONTH FROM logdate));
2156 </programlisting></para>
2158 <para>
2159 Create a list partitioned table:
2160 <programlisting>
2161 CREATE TABLE cities (
2162 city_id bigserial not null,
2163 name text not null,
2164 population bigint
2165 ) PARTITION BY LIST (left(lower(name), 1));
2166 </programlisting></para>
2168 <para>
2169 Create a hash partitioned table:
2170 <programlisting>
2171 CREATE TABLE orders (
2172 order_id bigint not null,
2173 cust_id bigint not null,
2174 status text
2175 ) PARTITION BY HASH (order_id);
2176 </programlisting></para>
2178 <para>
2179 Create partition of a range partitioned table:
2180 <programlisting>
2181 CREATE TABLE measurement_y2016m07
2182 PARTITION OF measurement (
2183 unitsales DEFAULT 0
2184 ) FOR VALUES FROM ('2016-07-01') TO ('2016-08-01');
2185 </programlisting></para>
2187 <para>
2188 Create a few partitions of a range partitioned table with multiple
2189 columns in the partition key:
2190 <programlisting>
2191 CREATE TABLE measurement_ym_older
2192 PARTITION OF measurement_year_month
2193 FOR VALUES FROM (MINVALUE, MINVALUE) TO (2016, 11);
2195 CREATE TABLE measurement_ym_y2016m11
2196 PARTITION OF measurement_year_month
2197 FOR VALUES FROM (2016, 11) TO (2016, 12);
2199 CREATE TABLE measurement_ym_y2016m12
2200 PARTITION OF measurement_year_month
2201 FOR VALUES FROM (2016, 12) TO (2017, 01);
2203 CREATE TABLE measurement_ym_y2017m01
2204 PARTITION OF measurement_year_month
2205 FOR VALUES FROM (2017, 01) TO (2017, 02);
2206 </programlisting></para>
2208 <para>
2209 Create partition of a list partitioned table:
2210 <programlisting>
2211 CREATE TABLE cities_ab
2212 PARTITION OF cities (
2213 CONSTRAINT city_id_nonzero CHECK (city_id != 0)
2214 ) FOR VALUES IN ('a', 'b');
2215 </programlisting></para>
2217 <para>
2218 Create partition of a list partitioned table that is itself further
2219 partitioned and then add a partition to it:
2220 <programlisting>
2221 CREATE TABLE cities_ab
2222 PARTITION OF cities (
2223 CONSTRAINT city_id_nonzero CHECK (city_id != 0)
2224 ) FOR VALUES IN ('a', 'b') PARTITION BY RANGE (population);
2226 CREATE TABLE cities_ab_10000_to_100000
2227 PARTITION OF cities_ab FOR VALUES FROM (10000) TO (100000);
2228 </programlisting></para>
2230 <para>
2231 Create partitions of a hash partitioned table:
2232 <programlisting>
2233 CREATE TABLE orders_p1 PARTITION OF orders
2234 FOR VALUES WITH (MODULUS 4, REMAINDER 0);
2235 CREATE TABLE orders_p2 PARTITION OF orders
2236 FOR VALUES WITH (MODULUS 4, REMAINDER 1);
2237 CREATE TABLE orders_p3 PARTITION OF orders
2238 FOR VALUES WITH (MODULUS 4, REMAINDER 2);
2239 CREATE TABLE orders_p4 PARTITION OF orders
2240 FOR VALUES WITH (MODULUS 4, REMAINDER 3);
2241 </programlisting></para>
2243 <para>
2244 Create a default partition:
2245 <programlisting>
2246 CREATE TABLE cities_partdef
2247 PARTITION OF cities DEFAULT;
2248 </programlisting></para>
2249 </refsect1>
2251 <refsect1 id="sql-createtable-compatibility" xreflabel="Compatibility">
2252 <title>Compatibility</title>
2254 <para>
2255 The <command>CREATE TABLE</command> command conforms to the
2256 <acronym>SQL</acronym> standard, with exceptions listed below.
2257 </para>
2259 <refsect2>
2260 <title>Temporary Tables</title>
2262 <para>
2263 Although the syntax of <literal>CREATE TEMPORARY TABLE</literal>
2264 resembles that of the SQL standard, the effect is not the same. In the
2265 standard,
2266 temporary tables are defined just once and automatically exist (starting
2267 with empty contents) in every session that needs them.
2268 <productname>PostgreSQL</productname> instead
2269 requires each session to issue its own <literal>CREATE TEMPORARY
2270 TABLE</literal> command for each temporary table to be used. This allows
2271 different sessions to use the same temporary table name for different
2272 purposes, whereas the standard's approach constrains all instances of a
2273 given temporary table name to have the same table structure.
2274 </para>
2276 <para>
2277 The standard's definition of the behavior of temporary tables is
2278 widely ignored. <productname>PostgreSQL</productname>'s behavior
2279 on this point is similar to that of several other SQL databases.
2280 </para>
2282 <para>
2283 The SQL standard also distinguishes between global and local temporary
2284 tables, where a local temporary table has a separate set of contents for
2285 each SQL module within each session, though its definition is still shared
2286 across sessions. Since <productname>PostgreSQL</productname> does not
2287 support SQL modules, this distinction is not relevant in
2288 <productname>PostgreSQL</productname>.
2289 </para>
2291 <para>
2292 For compatibility's sake, <productname>PostgreSQL</productname> will
2293 accept the <literal>GLOBAL</literal> and <literal>LOCAL</literal> keywords
2294 in a temporary table declaration, but they currently have no effect.
2295 Use of these keywords is discouraged, since future versions of
2296 <productname>PostgreSQL</productname> might adopt a more
2297 standard-compliant interpretation of their meaning.
2298 </para>
2300 <para>
2301 The <literal>ON COMMIT</literal> clause for temporary tables
2302 also resembles the SQL standard, but has some differences.
2303 If the <literal>ON COMMIT</literal> clause is omitted, SQL specifies that the
2304 default behavior is <literal>ON COMMIT DELETE ROWS</literal>. However, the
2305 default behavior in <productname>PostgreSQL</productname> is
2306 <literal>ON COMMIT PRESERVE ROWS</literal>. The <literal>ON COMMIT
2307 DROP</literal> option does not exist in SQL.
2308 </para>
2309 </refsect2>
2311 <refsect2>
2312 <title>Non-Deferred Uniqueness Constraints</title>
2314 <para>
2315 When a <literal>UNIQUE</literal> or <literal>PRIMARY KEY</literal> constraint is
2316 not deferrable, <productname>PostgreSQL</productname> checks for
2317 uniqueness immediately whenever a row is inserted or modified.
2318 The SQL standard says that uniqueness should be enforced only at
2319 the end of the statement; this makes a difference when, for example,
2320 a single command updates multiple key values. To obtain
2321 standard-compliant behavior, declare the constraint as
2322 <literal>DEFERRABLE</literal> but not deferred (i.e., <literal>INITIALLY
2323 IMMEDIATE</literal>). Be aware that this can be significantly slower than
2324 immediate uniqueness checking.
2325 </para>
2326 </refsect2>
2328 <refsect2>
2329 <title>Column Check Constraints</title>
2331 <para>
2332 The SQL standard says that <literal>CHECK</literal> column constraints
2333 can only refer to the column they apply to; only <literal>CHECK</literal>
2334 table constraints can refer to multiple columns.
2335 <productname>PostgreSQL</productname> does not enforce this
2336 restriction; it treats column and table check constraints alike.
2337 </para>
2338 </refsect2>
2340 <refsect2>
2341 <title><literal>EXCLUDE</literal> Constraint</title>
2343 <para>
2344 The <literal>EXCLUDE</literal> constraint type is a
2345 <productname>PostgreSQL</productname> extension.
2346 </para>
2347 </refsect2>
2349 <refsect2>
2350 <title>Foreign Key Constraints</title>
2352 <para>
2353 The ability to specify column lists in the foreign key actions
2354 <literal>SET DEFAULT</literal> and <literal>SET NULL</literal> is a
2355 <productname>PostgreSQL</productname> extension.
2356 </para>
2358 <para>
2359 It is a <productname>PostgreSQL</productname> extension that a
2360 foreign key constraint may reference columns of a unique index instead of
2361 columns of a primary key or unique constraint.
2362 </para>
2363 </refsect2>
2365 <refsect2>
2366 <title><literal>NULL</literal> <quote>Constraint</quote></title>
2368 <para>
2369 The <literal>NULL</literal> <quote>constraint</quote> (actually a
2370 non-constraint) is a <productname>PostgreSQL</productname>
2371 extension to the SQL standard that is included for compatibility with some
2372 other database systems (and for symmetry with the <literal>NOT
2373 NULL</literal> constraint). Since it is the default for any
2374 column, its presence is simply noise.
2375 </para>
2376 </refsect2>
2378 <refsect2>
2379 <title>Constraint Naming</title>
2381 <para>
2382 The SQL standard says that table and domain constraints must have names
2383 that are unique across the schema containing the table or domain.
2384 <productname>PostgreSQL</productname> is laxer: it only requires
2385 constraint names to be unique across the constraints attached to a
2386 particular table or domain. However, this extra freedom does not exist
2387 for index-based constraints (<literal>UNIQUE</literal>,
2388 <literal>PRIMARY KEY</literal>, and <literal>EXCLUDE</literal>
2389 constraints), because the associated index is named the same as the
2390 constraint, and index names must be unique across all relations within
2391 the same schema.
2392 </para>
2393 </refsect2>
2395 <refsect2>
2396 <title>Inheritance</title>
2398 <para>
2399 Multiple inheritance via the <literal>INHERITS</literal> clause is
2400 a <productname>PostgreSQL</productname> language extension.
2401 SQL:1999 and later define single inheritance using a
2402 different syntax and different semantics. SQL:1999-style
2403 inheritance is not yet supported by
2404 <productname>PostgreSQL</productname>.
2405 </para>
2406 </refsect2>
2408 <refsect2>
2409 <title>Zero-Column Tables</title>
2411 <para>
2412 <productname>PostgreSQL</productname> allows a table of no columns
2413 to be created (for example, <literal>CREATE TABLE foo();</literal>). This
2414 is an extension from the SQL standard, which does not allow zero-column
2415 tables. Zero-column tables are not in themselves very useful, but
2416 disallowing them creates odd special cases for <command>ALTER TABLE
2417 DROP COLUMN</command>, so it seems cleaner to ignore this spec restriction.
2418 </para>
2419 </refsect2>
2421 <refsect2>
2422 <title>Multiple Identity Columns</title>
2424 <para>
2425 <productname>PostgreSQL</productname> allows a table to have more than one
2426 identity column. The standard specifies that a table can have at most one
2427 identity column. This is relaxed mainly to give more flexibility for
2428 doing schema changes or migrations. Note that
2429 the <command>INSERT</command> command supports only one override clause
2430 that applies to the entire statement, so having multiple identity columns
2431 with different behaviors is not well supported.
2432 </para>
2433 </refsect2>
2435 <refsect2>
2436 <title>Generated Columns</title>
2438 <para>
2439 The option <literal>STORED</literal> is not standard but is also used by
2440 other SQL implementations. The SQL standard does not specify the storage
2441 of generated columns.
2442 </para>
2443 </refsect2>
2445 <refsect2>
2446 <title><literal>LIKE</literal> Clause</title>
2448 <para>
2449 While a <literal>LIKE</literal> clause exists in the SQL standard, many of the
2450 options that <productname>PostgreSQL</productname> accepts for it are not
2451 in the standard, and some of the standard's options are not implemented
2452 by <productname>PostgreSQL</productname>.
2453 </para>
2454 </refsect2>
2456 <refsect2>
2457 <title><literal>WITH</literal> Clause</title>
2459 <para>
2460 The <literal>WITH</literal> clause is a <productname>PostgreSQL</productname>
2461 extension; storage parameters are not in the standard.
2462 </para>
2463 </refsect2>
2465 <refsect2>
2466 <title>Tablespaces</title>
2468 <para>
2469 The <productname>PostgreSQL</productname> concept of tablespaces is not
2470 part of the standard. Hence, the clauses <literal>TABLESPACE</literal>
2471 and <literal>USING INDEX TABLESPACE</literal> are extensions.
2472 </para>
2473 </refsect2>
2475 <refsect2>
2476 <title>Typed Tables</title>
2478 <para>
2479 Typed tables implement a subset of the SQL standard. According to
2480 the standard, a typed table has columns corresponding to the
2481 underlying composite type as well as one other column that is
2482 the <quote>self-referencing column</quote>.
2483 <productname>PostgreSQL</productname> does not support self-referencing
2484 columns explicitly.
2485 </para>
2486 </refsect2>
2488 <refsect2>
2489 <title><literal>PARTITION BY</literal> Clause</title>
2491 <para>
2492 The <literal>PARTITION BY</literal> clause is a
2493 <productname>PostgreSQL</productname> extension.
2494 </para>
2495 </refsect2>
2497 <refsect2>
2498 <title><literal>PARTITION OF</literal> Clause</title>
2500 <para>
2501 The <literal>PARTITION OF</literal> clause is a
2502 <productname>PostgreSQL</productname> extension.
2503 </para>
2504 </refsect2>
2506 </refsect1>
2509 <refsect1>
2510 <title>See Also</title>
2512 <simplelist type="inline">
2513 <member><xref linkend="sql-altertable"/></member>
2514 <member><xref linkend="sql-droptable"/></member>
2515 <member><xref linkend="sql-createtableas"/></member>
2516 <member><xref linkend="sql-createtablespace"/></member>
2517 <member><xref linkend="sql-createtype"/></member>
2518 </simplelist>
2519 </refsect1>
2520 </refentry>