Make LC_COLLATE and LC_CTYPE database-level settings. Collation and
[PostgreSQL.git] / doc / src / sgml / ref / create_table.sgml
blob9dd6368cb5655d94dcef302f8ade7e049b9d693f
1 <!--
2 $PostgreSQL$
3 PostgreSQL documentation
4 -->
6 <refentry id="SQL-CREATETABLE">
7 <refmeta>
8 <refentrytitle id="sql-createtable-title">CREATE TABLE</refentrytitle>
9 <refmiscinfo>SQL - Language Statements</refmiscinfo>
10 </refmeta>
12 <refnamediv>
13 <refname>CREATE TABLE</refname>
14 <refpurpose>define a new table</refpurpose>
15 </refnamediv>
17 <indexterm zone="sql-createtable">
18 <primary>CREATE TABLE</primary>
19 </indexterm>
21 <refsynopsisdiv>
22 <synopsis>
23 CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } ] TABLE <replaceable class="PARAMETER">table_name</replaceable> ( [
24 { <replaceable class="PARAMETER">column_name</replaceable> <replaceable class="PARAMETER">data_type</replaceable> [ DEFAULT <replaceable>default_expr</> ] [ <replaceable class="PARAMETER">column_constraint</replaceable> [ ... ] ]
25 | <replaceable>table_constraint</replaceable>
26 | LIKE <replaceable>parent_table</replaceable> [ { INCLUDING | EXCLUDING } { DEFAULTS | CONSTRAINTS | INDEXES } ] ... }
27 [, ... ]
28 ] )
29 [ INHERITS ( <replaceable>parent_table</replaceable> [, ... ] ) ]
30 [ WITH ( <replaceable class="PARAMETER">storage_parameter</replaceable> [= <replaceable class="PARAMETER">value</replaceable>] [, ... ] ) | WITH OIDS | WITHOUT OIDS ]
31 [ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
32 [ TABLESPACE <replaceable class="PARAMETER">tablespace</replaceable> ]
34 where <replaceable class="PARAMETER">column_constraint</replaceable> is:
36 [ CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable> ]
37 { NOT NULL |
38 NULL |
39 UNIQUE <replaceable class="PARAMETER">index_parameters</replaceable> |
40 PRIMARY KEY <replaceable class="PARAMETER">index_parameters</replaceable> |
41 CHECK ( <replaceable class="PARAMETER">expression</replaceable> ) |
42 REFERENCES <replaceable class="PARAMETER">reftable</replaceable> [ ( <replaceable class="PARAMETER">refcolumn</replaceable> ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ]
43 [ ON DELETE <replaceable class="parameter">action</replaceable> ] [ ON UPDATE <replaceable class="parameter">action</replaceable> ] }
44 [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
46 and <replaceable class="PARAMETER">table_constraint</replaceable> is:
48 [ CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable> ]
49 { UNIQUE ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] ) <replaceable class="PARAMETER">index_parameters</replaceable> |
50 PRIMARY KEY ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] ) <replaceable class="PARAMETER">index_parameters</replaceable> |
51 CHECK ( <replaceable class="PARAMETER">expression</replaceable> ) |
52 FOREIGN KEY ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] ) REFERENCES <replaceable class="PARAMETER">reftable</replaceable> [ ( <replaceable class="PARAMETER">refcolumn</replaceable> [, ... ] ) ]
53 [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ] [ ON DELETE <replaceable class="parameter">action</replaceable> ] [ ON UPDATE <replaceable class="parameter">action</replaceable> ] }
54 [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
56 <replaceable class="PARAMETER">index_parameters</replaceable> in <literal>UNIQUE</> and <literal>PRIMARY KEY</> constraints are:
58 [ WITH ( <replaceable class="PARAMETER">storage_parameter</replaceable> [= <replaceable class="PARAMETER">value</replaceable>] [, ... ] ) ]
59 [ USING INDEX TABLESPACE <replaceable class="PARAMETER">tablespace</replaceable> ]
60 </synopsis>
62 </refsynopsisdiv>
64 <refsect1 id="SQL-CREATETABLE-description">
65 <title>Description</title>
67 <para>
68 <command>CREATE TABLE</command> will create a new, initially empty table
69 in the current database. The table will be owned by the user issuing the
70 command.
71 </para>
73 <para>
74 If a schema name is given (for example, <literal>CREATE TABLE
75 myschema.mytable ...</>) then the table is created in the specified
76 schema. Otherwise it is created in the current schema. Temporary
77 tables exist in a special schema, so a schema name cannot be given
78 when creating a temporary table. The name of the table must be
79 distinct from the name of any other table, sequence, index, or view
80 in the same schema.
81 </para>
83 <para>
84 <command>CREATE TABLE</command> also automatically creates a data
85 type that represents the composite type corresponding
86 to one row of the table. Therefore, tables cannot have the same
87 name as any existing data type in the same schema.
88 </para>
90 <para>
91 The optional constraint clauses specify constraints (tests) that
92 new or updated rows must satisfy for an insert or update operation
93 to succeed. A constraint is an SQL object that helps define the
94 set of valid values in the table in various ways.
95 </para>
97 <para>
98 There are two ways to define constraints: table constraints and
99 column constraints. A column constraint is defined as part of a
100 column definition. A table constraint definition is not tied to a
101 particular column, and it can encompass more than one column.
102 Every column constraint can also be written as a table constraint;
103 a column constraint is only a notational convenience for use when the
104 constraint only affects one column.
105 </para>
106 </refsect1>
108 <refsect1>
109 <title>Parameters</title>
111 <variablelist>
113 <varlistentry>
114 <term><literal>TEMPORARY</> or <literal>TEMP</></term>
115 <listitem>
116 <para>
117 If specified, the table is created as a temporary table.
118 Temporary tables are automatically dropped at the end of a
119 session, or optionally at the end of the current transaction
120 (see <literal>ON COMMIT</literal> below). Existing permanent
121 tables with the same name are not visible to the current session
122 while the temporary table exists, unless they are referenced
123 with schema-qualified names. Any indexes created on a temporary
124 table are automatically temporary as well.
125 </para>
127 <para>
128 Optionally, <literal>GLOBAL</literal> or <literal>LOCAL</literal>
129 can be written before <literal>TEMPORARY</> or <literal>TEMP</>.
130 This makes no difference in <productname>PostgreSQL</>, but see
131 <xref linkend="sql-createtable-compatibility"
132 endterm="sql-createtable-compatibility-title">.
133 </para>
134 </listitem>
135 </varlistentry>
137 <varlistentry>
138 <term><replaceable class="PARAMETER">table_name</replaceable></term>
139 <listitem>
140 <para>
141 The name (optionally schema-qualified) of the table to be created.
142 </para>
143 </listitem>
144 </varlistentry>
146 <varlistentry>
147 <term><replaceable class="PARAMETER">column_name</replaceable></term>
148 <listitem>
149 <para>
150 The name of a column to be created in the new table.
151 </para>
152 </listitem>
153 </varlistentry>
155 <varlistentry>
156 <term><replaceable class="PARAMETER">data_type</replaceable></term>
157 <listitem>
158 <para>
159 The data type of the column. This can include array
160 specifiers. For more information on the data types supported by
161 <productname>PostgreSQL</productname>, refer to <xref
162 linkend="datatype">.
163 </para>
164 </listitem>
165 </varlistentry>
167 <varlistentry>
168 <term><literal>DEFAULT
169 <replaceable>default_expr</replaceable></literal></term>
170 <listitem>
171 <para>
172 The <literal>DEFAULT</> clause assigns a default data value for
173 the column whose column definition it appears within. The value
174 is any variable-free expression (subqueries and cross-references
175 to other columns in the current table are not allowed). The
176 data type of the default expression must match the data type of the
177 column.
178 </para>
180 <para>
181 The default expression will be used in any insert operation that
182 does not specify a value for the column. If there is no default
183 for a column, then the default is null.
184 </para>
185 </listitem>
186 </varlistentry>
188 <varlistentry>
189 <term><literal>INHERITS ( <replaceable>parent_table</replaceable> [, ... ] )</literal></term>
190 <listitem>
191 <para>
192 The optional <literal>INHERITS</> clause specifies a list of
193 tables from which the new table automatically inherits all
194 columns.
195 </para>
197 <para>
198 Use of <literal>INHERITS</> creates a persistent relationship
199 between the new child table and its parent table(s). Schema
200 modifications to the parent(s) normally propagate to children
201 as well, and by default the data of the child table is included in
202 scans of the parent(s).
203 </para>
205 <para>
206 If the same column name exists in more than one parent
207 table, an error is reported unless the data types of the columns
208 match in each of the parent tables. If there is no conflict,
209 then the duplicate columns are merged to form a single column in
210 the new table. If the column name list of the new table
211 contains a column name that is also inherited, the data type must
212 likewise match the inherited column(s), and the column
213 definitions are merged into one. If the
214 new table explicitly specifies a default value for the column,
215 this default overrides any defaults from inherited declarations
216 of the column. Otherwise, any parents that specify default
217 values for the column must all specify the same default, or an
218 error will be reported.
219 </para>
221 <para>
222 <literal>CHECK</> constraints are merged in essentially the same way as
223 columns: if multiple parent tables and/or the new table definition
224 contain identically-named <literal>CHECK</> constraints, these
225 constraints must all have the same check expression, or an error will be
226 reported. Constraints having the same name and expression will
227 be merged into one copy. Notice that an unnamed <literal>CHECK</>
228 constraint in the new table will never be merged, since a unique name
229 will always be chosen for it.
230 </para>
232 <!--
233 <para>
234 <productname>PostgreSQL</> automatically allows the
235 created table to inherit
236 functions on tables above it in the inheritance hierarchy; that
237 is, if we create table <literal>foo</literal> inheriting from
238 <literal>bar</literal>, then functions that accept the tuple
239 type <literal>bar</literal> can also be applied to instances of
240 <literal>foo</literal>. (Currently, this works reliably for
241 functions on the first or only parent table, but not so well for
242 functions on additional parents.)
243 </para>
245 </listitem>
246 </varlistentry>
248 <varlistentry>
249 <term><literal>LIKE <replaceable>parent_table</replaceable> [ { INCLUDING | EXCLUDING } { DEFAULTS | CONSTRAINTS | INDEXES } ]</literal></term>
250 <listitem>
251 <para>
252 The <literal>LIKE</literal> clause specifies a table from which
253 the new table automatically copies all column names, their data types,
254 and their not-null constraints.
255 </para>
256 <para>
257 Unlike <literal>INHERITS</literal>, the new table and original table
258 are completely decoupled after creation is complete. Changes to the
259 original table will not be applied to the new table, and it is not
260 possible to include data of the new table in scans of the original
261 table.
262 </para>
263 <para>
264 Default expressions for the copied column definitions will only be
265 copied if <literal>INCLUDING DEFAULTS</literal> is specified. The
266 default behavior is to exclude default expressions, resulting in the
267 copied columns in the new table having null defaults.
268 </para>
269 <para>
270 Not-null constraints are always copied to the new table.
271 <literal>CHECK</literal> constraints will only be copied if
272 <literal>INCLUDING CONSTRAINTS</literal> is specified; other types of
273 constraints will never be copied. Also, no distinction is made between
274 column constraints and table constraints &mdash; when constraints are
275 requested, all check constraints are copied.
276 </para>
277 <para>
278 Any indexes on the original table will not be created on the new
279 table, unless the <literal>INCLUDING INDEXES</literal> clause is
280 specified.
281 </para>
282 <para>
283 Note also that unlike <literal>INHERITS</literal>, copied columns and
284 constraints are not merged with similarly named columns and constraints.
285 If the same name is specified explicitly or in another
286 <literal>LIKE</literal> clause, an error is signalled.
287 </para>
288 </listitem>
289 </varlistentry>
291 <varlistentry>
292 <term><literal>CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable></literal></term>
293 <listitem>
294 <para>
295 An optional name for a column or table constraint. If the
296 constraint is violated, the constraint name is present in error messages,
297 so constraint names like <literal>col must be positive</> can be used
298 to communicate helpful constraint information to client applications.
299 (Double-quotes are needed to specify constraint names that contain spaces.)
300 If a constraint name is not specified, the system generates a name.
301 </para>
302 </listitem>
303 </varlistentry>
305 <varlistentry>
306 <term><literal>NOT NULL</></term>
307 <listitem>
308 <para>
309 The column is not allowed to contain null values.
310 </para>
311 </listitem>
312 </varlistentry>
314 <varlistentry>
315 <term><literal>NULL</></term>
316 <listitem>
317 <para>
318 The column is allowed to contain null values. This is the default.
319 </para>
321 <para>
322 This clause is only provided for compatibility with
323 non-standard SQL databases. Its use is discouraged in new
324 applications.
325 </para>
326 </listitem>
327 </varlistentry>
329 <varlistentry>
330 <term><literal>UNIQUE</> (column constraint)</term>
331 <term><literal>UNIQUE ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] )</> (table constraint)</term>
333 <listitem>
334 <para>
335 The <literal>UNIQUE</literal> constraint specifies that a
336 group of one or more columns of a table can contain
337 only unique values. The behavior of the unique table constraint
338 is the same as that for column constraints, with the additional
339 capability to span multiple columns.
340 </para>
342 <para>
343 For the purpose of a unique constraint, null values are not
344 considered equal.
345 </para>
347 <para>
348 Each unique table constraint must name a set of columns that is
349 different from the set of columns named by any other unique or
350 primary key constraint defined for the table. (Otherwise it
351 would just be the same constraint listed twice.)
352 </para>
353 </listitem>
354 </varlistentry>
356 <varlistentry>
357 <term><literal>PRIMARY KEY</> (column constraint)</term>
358 <term><literal>PRIMARY KEY ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] )</> (table constraint)</term>
359 <listitem>
360 <para>
361 The primary key constraint specifies that a column or columns of a table
362 can contain only unique (non-duplicate), nonnull values.
363 Technically, <literal>PRIMARY KEY</literal> is merely a
364 combination of <literal>UNIQUE</> and <literal>NOT NULL</>, but
365 identifying a set of columns as primary key also provides
366 metadata about the design of the schema, as a primary key
367 implies that other tables
368 can rely on this set of columns as a unique identifier for rows.
369 </para>
371 <para>
372 Only one primary key can be specified for a table, whether as a
373 column constraint or a table constraint.
374 </para>
376 <para>
377 The primary key constraint should name a set of columns that is
378 different from other sets of columns named by any unique
379 constraint defined for the same table.
380 </para>
381 </listitem>
382 </varlistentry>
384 <varlistentry>
385 <term><literal>CHECK ( <replaceable class="PARAMETER">expression</replaceable> )</literal></term>
386 <listitem>
387 <para>
388 The <literal>CHECK</> clause specifies an expression producing a
389 Boolean result which new or updated rows must satisfy for an
390 insert or update operation to succeed. Expressions evaluating
391 to TRUE or UNKNOWN succeed. Should any row of an insert or
392 update operation produce a FALSE result an error exception is
393 raised and the insert or update does not alter the database. A
394 check constraint specified as a column constraint should
395 reference that column's value only, while an expression
396 appearing in a table constraint can reference multiple columns.
397 </para>
399 <para>
400 Currently, <literal>CHECK</literal> expressions cannot contain
401 subqueries nor refer to variables other than columns of the
402 current row.
403 </para>
404 </listitem>
405 </varlistentry>
408 <varlistentry>
409 <term><literal>REFERENCES <replaceable class="parameter">reftable</replaceable> [ ( <replaceable class="parameter">refcolumn</replaceable> ) ] [ MATCH <replaceable class="parameter">matchtype</replaceable> ] [ ON DELETE <replaceable class="parameter">action</replaceable> ] [ ON UPDATE <replaceable class="parameter">action</replaceable> ]</literal> (column constraint)</term>
411 <term><literal>FOREIGN KEY ( <replaceable class="parameter">column</replaceable> [, ... ] )
412 REFERENCES <replaceable class="parameter">reftable</replaceable> [ ( <replaceable class="parameter">refcolumn</replaceable> [, ... ] ) ]
413 [ MATCH <replaceable class="parameter">matchtype</replaceable> ]
414 [ ON DELETE <replaceable class="parameter">action</replaceable> ]
415 [ ON UPDATE <replaceable class="parameter">action</replaceable> ]</literal>
416 (table constraint)</term>
418 <listitem>
419 <para>
420 These clauses specify a foreign key constraint, which requires
421 that a group of one or more columns of the new table must only
422 contain values that match values in the referenced
423 column(s) of some row of the referenced table. If <replaceable
424 class="parameter">refcolumn</replaceable> is omitted, the
425 primary key of the <replaceable
426 class="parameter">reftable</replaceable> is used. The
427 referenced columns must be the columns of a unique or primary
428 key constraint in the referenced table. Note that foreign key
429 constraints cannot be defined between temporary tables and
430 permanent tables.
431 </para>
433 <para>
434 A value inserted into the referencing column(s) is matched against the
435 values of the referenced table and referenced columns using the
436 given match type. There are three match types: <literal>MATCH
437 FULL</>, <literal>MATCH PARTIAL</>, and <literal>MATCH
438 SIMPLE</literal>, which is also the default. <literal>MATCH
439 FULL</> will not allow one column of a multicolumn foreign key
440 to be null unless all foreign key columns are null.
441 <literal>MATCH SIMPLE</literal> allows some foreign key columns
442 to be null while other parts of the foreign key are not
443 null. <literal>MATCH PARTIAL</> is not yet implemented.
444 </para>
446 <para>
447 In addition, when the data in the referenced columns is changed,
448 certain actions are performed on the data in this table's
449 columns. The <literal>ON DELETE</literal> clause specifies the
450 action to perform when a referenced row in the referenced table is
451 being deleted. Likewise, the <literal>ON UPDATE</literal>
452 clause specifies the action to perform when a referenced column
453 in the referenced table is being updated to a new value. If the
454 row is updated, but the referenced column is not actually
455 changed, no action is done. Referential actions other than the
456 <literal>NO ACTION</literal> check cannot be deferred, even if
457 the constraint is declared deferrable. There are the following possible
458 actions for each clause:
460 <variablelist>
461 <varlistentry>
462 <term><literal>NO ACTION</literal></term>
463 <listitem>
464 <para>
465 Produce an error indicating that the deletion or update
466 would create a foreign key constraint violation.
467 If the constraint is deferred, this
468 error will be produced at constraint check time if there still
469 exist any referencing rows. This is the default action.
470 </para>
471 </listitem>
472 </varlistentry>
474 <varlistentry>
475 <term><literal>RESTRICT</literal></term>
476 <listitem>
477 <para>
478 Produce an error indicating that the deletion or update
479 would create a foreign key constraint violation.
480 This is the same as <literal>NO ACTION</literal> except that
481 the check is not deferrable.
482 </para>
483 </listitem>
484 </varlistentry>
486 <varlistentry>
487 <term><literal>CASCADE</literal></term>
488 <listitem>
489 <para>
490 Delete any rows referencing the deleted row, or update the
491 value of the referencing column to the new value of the
492 referenced column, respectively.
493 </para>
494 </listitem>
495 </varlistentry>
497 <varlistentry>
498 <term><literal>SET NULL</literal></term>
499 <listitem>
500 <para>
501 Set the referencing column(s) to null.
502 </para>
503 </listitem>
504 </varlistentry>
506 <varlistentry>
507 <term><literal>SET DEFAULT</literal></term>
508 <listitem>
509 <para>
510 Set the referencing column(s) to their default values.
511 </para>
512 </listitem>
513 </varlistentry>
514 </variablelist>
515 </para>
517 <para>
518 If the referenced column(s) are changed frequently, it might be wise to
519 add an index to the foreign key column so that referential actions
520 associated with the foreign key column can be performed more
521 efficiently.
522 </para>
523 </listitem>
524 </varlistentry>
526 <varlistentry>
527 <term><literal>DEFERRABLE</literal></term>
528 <term><literal>NOT DEFERRABLE</literal></term>
529 <listitem>
530 <para>
531 This controls whether the constraint can be deferred. A
532 constraint that is not deferrable will be checked immediately
533 after every command. Checking of constraints that are
534 deferrable can be postponed until the end of the transaction
535 (using the <xref linkend="sql-set-constraints" endterm="sql-set-constraints-title"> command).
536 <literal>NOT DEFERRABLE</literal> is the default. Only foreign
537 key constraints currently accept this clause. All other
538 constraint types are not deferrable.
539 </para>
540 </listitem>
541 </varlistentry>
543 <varlistentry>
544 <term><literal>INITIALLY IMMEDIATE</literal></term>
545 <term><literal>INITIALLY DEFERRED</literal></term>
546 <listitem>
547 <para>
548 If a constraint is deferrable, this clause specifies the default
549 time to check the constraint. If the constraint is
550 <literal>INITIALLY IMMEDIATE</literal>, it is checked after each
551 statement. This is the default. If the constraint is
552 <literal>INITIALLY DEFERRED</literal>, it is checked only at the
553 end of the transaction. The constraint check time can be
554 altered with the <xref linkend="sql-set-constraints" endterm="sql-set-constraints-title"> command.
555 </para>
556 </listitem>
557 </varlistentry>
559 <varlistentry>
560 <term><literal>WITH ( <replaceable class="PARAMETER">storage_parameter</replaceable> [= <replaceable class="PARAMETER">value</replaceable>] [, ... ] )</literal></term>
561 <listitem>
562 <para>
563 This clause specifies optional storage parameters for a table or index;
564 see <xref linkend="sql-createtable-storage-parameters"
565 endterm="sql-createtable-storage-parameters-title"> for more
566 information. The <literal>WITH</> clause for a
567 table can also include <literal>OIDS=TRUE</> (or just <literal>OIDS</>)
568 to specify that rows of the new table
569 should have OIDs (object identifiers) assigned to them, or
570 <literal>OIDS=FALSE</> to specify that the rows should not have OIDs.
571 If <literal>OIDS</> is not specified, the default setting depends upon
572 the <xref linkend="guc-default-with-oids"> configuration parameter.
573 (If the new table inherits from any tables that have OIDs, then
574 <literal>OIDS=TRUE</> is forced even if the command says
575 <literal>OIDS=FALSE</>.)
576 </para>
578 <para>
579 If <literal>OIDS=FALSE</literal> is specified or implied, the new
580 table does not store OIDs and no OID will be assigned for a row inserted
581 into it. This is generally considered worthwhile, since it
582 will reduce OID consumption and thereby postpone the wraparound
583 of the 32-bit OID counter. Once the counter wraps around, OIDs
584 can no longer be assumed to be unique, which makes them
585 considerably less useful. In addition, excluding OIDs from a
586 table reduces the space required to store the table on disk by
587 4 bytes per row (on most machines), slightly improving performance.
588 </para>
590 <para>
591 To remove OIDs from a table after it has been created, use <xref
592 linkend="sql-altertable" endterm="sql-altertable-title">.
593 </para>
594 </listitem>
595 </varlistentry>
597 <varlistentry>
598 <term><literal>WITH OIDS</></term>
599 <term><literal>WITHOUT OIDS</></term>
600 <listitem>
601 <para>
602 These are obsolescent syntaxes equivalent to <literal>WITH (OIDS)</>
603 and <literal>WITH (OIDS=FALSE)</>, respectively. If you wish to give
604 both an <literal>OIDS</> setting and storage parameters, you must use
605 the <literal>WITH ( ... )</> syntax; see above.
606 </para>
607 </listitem>
608 </varlistentry>
610 <varlistentry>
611 <term><literal>ON COMMIT</literal></term>
612 <listitem>
613 <para>
614 The behavior of temporary tables at the end of a transaction
615 block can be controlled using <literal>ON COMMIT</literal>.
616 The three options are:
618 <variablelist>
619 <varlistentry>
620 <term><literal>PRESERVE ROWS</literal></term>
621 <listitem>
622 <para>
623 No special action is taken at the ends of transactions.
624 This is the default behavior.
625 </para>
626 </listitem>
627 </varlistentry>
629 <varlistentry>
630 <term><literal>DELETE ROWS</literal></term>
631 <listitem>
632 <para>
633 All rows in the temporary table will be deleted at the end
634 of each transaction block. Essentially, an automatic <xref
635 linkend="sql-truncate" endterm="sql-truncate-title"> is done
636 at each commit.
637 </para>
638 </listitem>
639 </varlistentry>
641 <varlistentry>
642 <term><literal>DROP</literal></term>
643 <listitem>
644 <para>
645 The temporary table will be dropped at the end of the current
646 transaction block.
647 </para>
648 </listitem>
649 </varlistentry>
650 </variablelist>
651 </para>
652 </listitem>
653 </varlistentry>
655 <varlistentry>
656 <term><literal>TABLESPACE <replaceable class="PARAMETER">tablespace</replaceable></literal></term>
657 <listitem>
658 <para>
659 The <replaceable class="PARAMETER">tablespace</replaceable> is the name
660 of the tablespace in which the new table is to be created.
661 If not specified,
662 <xref linkend="guc-default-tablespace"> is consulted, or
663 <xref linkend="guc-temp-tablespaces"> if the table is temporary.
664 </para>
665 </listitem>
666 </varlistentry>
668 <varlistentry>
669 <term><literal>USING INDEX TABLESPACE <replaceable class="PARAMETER">tablespace</replaceable></literal></term>
670 <listitem>
671 <para>
672 This clause allows selection of the tablespace in which the index
673 associated with a <literal>UNIQUE</literal> or <literal>PRIMARY
674 KEY</literal> constraint will be created.
675 If not specified,
676 <xref linkend="guc-default-tablespace"> is consulted, or
677 <xref linkend="guc-temp-tablespaces"> if the table is temporary.
678 </para>
679 </listitem>
680 </varlistentry>
682 </variablelist>
684 <refsect2 id="SQL-CREATETABLE-storage-parameters">
685 <title id="SQL-CREATETABLE-storage-parameters-title">Storage Parameters</title>
687 <para>
688 The <literal>WITH</> clause can specify <firstterm>storage parameters</>
689 for tables, and for indexes associated with a <literal>UNIQUE</literal> or
690 <literal>PRIMARY KEY</literal> constraint. Storage parameters for
691 indexes are documented in <xref linkend="SQL-CREATEINDEX"
692 endterm="sql-createindex-title">. The only storage parameter currently
693 available for tables is:
694 </para>
696 <variablelist>
698 <varlistentry>
699 <term><literal>FILLFACTOR</></term>
700 <listitem>
701 <para>
702 The fillfactor for a table is a percentage between 10 and 100.
703 100 (complete packing) is the default. When a smaller fillfactor
704 is specified, <command>INSERT</> operations pack table pages only
705 to the indicated percentage; the remaining space on each page is
706 reserved for updating rows on that page. This gives <command>UPDATE</>
707 a chance to place the updated copy of a row on the same page as the
708 original, which is more efficient than placing it on a different page.
709 For a table whose entries are never updated, complete packing is the
710 best choice, but in heavily updated tables smaller fillfactors are
711 appropriate.
712 </para>
713 </listitem>
714 </varlistentry>
716 </variablelist>
718 </refsect2>
719 </refsect1>
721 <refsect1 id="SQL-CREATETABLE-notes">
722 <title>Notes</title>
724 <para>
725 Using OIDs in new applications is not recommended: where
726 possible, using a <literal>SERIAL</literal> or other sequence
727 generator as the table's primary key is preferred. However, if
728 your application does make use of OIDs to identify specific
729 rows of a table, it is recommended to create a unique constraint
730 on the <structfield>oid</> column of that table, to ensure that
731 OIDs in the table will indeed uniquely identify rows even after
732 counter wraparound. Avoid assuming that OIDs are unique across
733 tables; if you need a database-wide unique identifier, use the
734 combination of <structfield>tableoid</> and row OID for the
735 purpose.
736 </para>
738 <tip>
739 <para>
740 The use of <literal>OIDS=FALSE</literal> is not recommended
741 for tables with no primary key, since without either an OID or a
742 unique data key, it is difficult to identify specific rows.
743 </para>
744 </tip>
746 <para>
747 <productname>PostgreSQL</productname> automatically creates an
748 index for each unique constraint and primary key constraint to
749 enforce uniqueness. Thus, it is not necessary to create an
750 index explicitly for primary key columns. (See <xref
751 linkend="sql-createindex" endterm="sql-createindex-title"> for more information.)
752 </para>
754 <para>
755 Unique constraints and primary keys are not inherited in the
756 current implementation. This makes the combination of
757 inheritance and unique constraints rather dysfunctional.
758 </para>
760 <para>
761 A table cannot have more than 1600 columns. (In practice, the
762 effective limit is usually lower because of tuple-length constraints.)
763 </para>
765 </refsect1>
768 <refsect1 id="SQL-CREATETABLE-examples">
769 <title>Examples</title>
771 <para>
772 Create table <structname>films</> and table
773 <structname>distributors</>:
775 <programlisting>
776 CREATE TABLE films (
777 code char(5) CONSTRAINT firstkey PRIMARY KEY,
778 title varchar(40) NOT NULL,
779 did integer NOT NULL,
780 date_prod date,
781 kind varchar(10),
782 len interval hour to minute
784 </programlisting>
786 <programlisting>
787 CREATE TABLE distributors (
788 did integer PRIMARY KEY DEFAULT nextval('serial'),
789 name varchar(40) NOT NULL CHECK (name &lt;&gt; '')
791 </programlisting>
792 </para>
794 <para>
795 Create a table with a 2-dimensional array:
797 <programlisting>
798 CREATE TABLE array_int (
799 vector int[][]
801 </programlisting>
802 </para>
804 <para>
805 Define a unique table constraint for the table
806 <literal>films</literal>. Unique table constraints can be defined
807 on one or more columns of the table:
809 <programlisting>
810 CREATE TABLE films (
811 code char(5),
812 title varchar(40),
813 did integer,
814 date_prod date,
815 kind varchar(10),
816 len interval hour to minute,
817 CONSTRAINT production UNIQUE(date_prod)
819 </programlisting>
820 </para>
822 <para>
823 Define a check column constraint:
825 <programlisting>
826 CREATE TABLE distributors (
827 did integer CHECK (did &gt; 100),
828 name varchar(40)
830 </programlisting>
831 </para>
833 <para>
834 Define a check table constraint:
836 <programlisting>
837 CREATE TABLE distributors (
838 did integer,
839 name varchar(40)
840 CONSTRAINT con1 CHECK (did &gt; 100 AND name &lt;&gt; '')
842 </programlisting>
843 </para>
845 <para>
846 Define a primary key table constraint for the table
847 <structname>films</>:
849 <programlisting>
850 CREATE TABLE films (
851 code char(5),
852 title varchar(40),
853 did integer,
854 date_prod date,
855 kind varchar(10),
856 len interval hour to minute,
857 CONSTRAINT code_title PRIMARY KEY(code,title)
859 </programlisting>
860 </para>
862 <para>
863 Define a primary key constraint for table
864 <structname>distributors</>. The following two examples are
865 equivalent, the first using the table constraint syntax, the second
866 the column constraint syntax:
868 <programlisting>
869 CREATE TABLE distributors (
870 did integer,
871 name varchar(40),
872 PRIMARY KEY(did)
874 </programlisting>
876 <programlisting>
877 CREATE TABLE distributors (
878 did integer PRIMARY KEY,
879 name varchar(40)
881 </programlisting>
882 </para>
884 <para>
885 Assign a literal constant default value for the column
886 <literal>name</literal>, arrange for the default value of column
887 <literal>did</literal> to be generated by selecting the next value
888 of a sequence object, and make the default value of
889 <literal>modtime</literal> be the time at which the row is
890 inserted:
892 <programlisting>
893 CREATE TABLE distributors (
894 name varchar(40) DEFAULT 'Luso Films',
895 did integer DEFAULT nextval('distributors_serial'),
896 modtime timestamp DEFAULT current_timestamp
898 </programlisting>
899 </para>
901 <para>
902 Define two <literal>NOT NULL</> column constraints on the table
903 <classname>distributors</classname>, one of which is explicitly
904 given a name:
906 <programlisting>
907 CREATE TABLE distributors (
908 did integer CONSTRAINT no_null NOT NULL,
909 name varchar(40) NOT NULL
911 </programlisting>
912 </para>
914 <para>
915 Define a unique constraint for the <literal>name</literal> column:
917 <programlisting>
918 CREATE TABLE distributors (
919 did integer,
920 name varchar(40) UNIQUE
922 </programlisting>
924 The same, specified as a table constraint:
926 <programlisting>
927 CREATE TABLE distributors (
928 did integer,
929 name varchar(40),
930 UNIQUE(name)
932 </programlisting>
933 </para>
935 <para>
936 Create the same table, specifying 70% fill factor for both the table
937 and its unique index:
939 <programlisting>
940 CREATE TABLE distributors (
941 did integer,
942 name varchar(40),
943 UNIQUE(name) WITH (fillfactor=70)
945 WITH (fillfactor=70);
946 </programlisting>
947 </para>
949 <para>
950 Create table <structname>cinemas</> in tablespace <structname>diskvol1</>:
952 <programlisting>
953 CREATE TABLE cinemas (
954 id serial,
955 name text,
956 location text
957 ) TABLESPACE diskvol1;
958 </programlisting>
959 </para>
961 </refsect1>
963 <refsect1 id="SQL-CREATETABLE-compatibility">
964 <title id="SQL-CREATETABLE-compatibility-title">Compatibility</title>
966 <para>
967 The <command>CREATE TABLE</command> command conforms to the
968 <acronym>SQL</acronym> standard, with exceptions listed below.
969 </para>
971 <refsect2>
972 <title>Temporary Tables</title>
974 <para>
975 Although the syntax of <literal>CREATE TEMPORARY TABLE</literal>
976 resembles that of the SQL standard, the effect is not the same. In the
977 standard,
978 temporary tables are defined just once and automatically exist (starting
979 with empty contents) in every session that needs them.
980 <productname>PostgreSQL</productname> instead
981 requires each session to issue its own <literal>CREATE TEMPORARY
982 TABLE</literal> command for each temporary table to be used. This allows
983 different sessions to use the same temporary table name for different
984 purposes, whereas the standard's approach constrains all instances of a
985 given temporary table name to have the same table structure.
986 </para>
988 <para>
989 The standard's definition of the behavior of temporary tables is
990 widely ignored. <productname>PostgreSQL</productname>'s behavior
991 on this point is similar to that of several other SQL databases.
992 </para>
994 <para>
995 The standard's distinction between global and local temporary tables
996 is not in <productname>PostgreSQL</productname>, since that distinction
997 depends on the concept of modules, which
998 <productname>PostgreSQL</productname> does not have.
999 For compatibility's sake, <productname>PostgreSQL</productname> will
1000 accept the <literal>GLOBAL</literal> and <literal>LOCAL</literal> keywords
1001 in a temporary table declaration, but they have no effect.
1002 </para>
1004 <para>
1005 The <literal>ON COMMIT</literal> clause for temporary tables
1006 also resembles the SQL standard, but has some differences.
1007 If the <literal>ON COMMIT</> clause is omitted, SQL specifies that the
1008 default behavior is <literal>ON COMMIT DELETE ROWS</>. However, the
1009 default behavior in <productname>PostgreSQL</productname> is
1010 <literal>ON COMMIT PRESERVE ROWS</literal>. The <literal>ON COMMIT
1011 DROP</literal> option does not exist in SQL.
1012 </para>
1013 </refsect2>
1015 <refsect2>
1016 <title>Column Check Constraints</title>
1018 <para>
1019 The SQL standard says that <literal>CHECK</> column constraints
1020 can only refer to the column they apply to; only <literal>CHECK</>
1021 table constraints can refer to multiple columns.
1022 <productname>PostgreSQL</productname> does not enforce this
1023 restriction; it treats column and table check constraints alike.
1024 </para>
1025 </refsect2>
1027 <refsect2>
1028 <title><literal>NULL</literal> <quote>Constraint</quote></title>
1030 <para>
1031 The <literal>NULL</> <quote>constraint</quote> (actually a
1032 non-constraint) is a <productname>PostgreSQL</productname>
1033 extension to the SQL standard that is included for compatibility with some
1034 other database systems (and for symmetry with the <literal>NOT
1035 NULL</literal> constraint). Since it is the default for any
1036 column, its presence is simply noise.
1037 </para>
1038 </refsect2>
1040 <refsect2>
1041 <title>Inheritance</title>
1043 <para>
1044 Multiple inheritance via the <literal>INHERITS</literal> clause is
1045 a <productname>PostgreSQL</productname> language extension.
1046 SQL:1999 and later define single inheritance using a
1047 different syntax and different semantics. SQL:1999-style
1048 inheritance is not yet supported by
1049 <productname>PostgreSQL</productname>.
1050 </para>
1051 </refsect2>
1053 <refsect2>
1054 <title>Zero-column tables</title>
1056 <para>
1057 <productname>PostgreSQL</productname> allows a table of no columns
1058 to be created (for example, <literal>CREATE TABLE foo();</>). This
1059 is an extension from the SQL standard, which does not allow zero-column
1060 tables. Zero-column tables are not in themselves very useful, but
1061 disallowing them creates odd special cases for <command>ALTER TABLE
1062 DROP COLUMN</>, so it seems cleaner to ignore this spec restriction.
1063 </para>
1064 </refsect2>
1066 <refsect2>
1067 <title><literal>WITH</> clause</title>
1069 <para>
1070 The <literal>WITH</> clause is a <productname>PostgreSQL</productname>
1071 extension; neither storage parameters nor OIDs are in the standard.
1072 </para>
1073 </refsect2>
1075 <refsect2>
1076 <title>Tablespaces</title>
1078 <para>
1079 The <productname>PostgreSQL</productname> concept of tablespaces is not
1080 part of the standard. Hence, the clauses <literal>TABLESPACE</literal>
1081 and <literal>USING INDEX TABLESPACE</literal> are extensions.
1082 </para>
1083 </refsect2>
1084 </refsect1>
1087 <refsect1>
1088 <title>See Also</title>
1090 <simplelist type="inline">
1091 <member><xref linkend="sql-altertable" endterm="sql-altertable-title"></member>
1092 <member><xref linkend="sql-droptable" endterm="sql-droptable-title"></member>
1093 <member><xref linkend="sql-createtablespace" endterm="sql-createtablespace-title"></member>
1094 </simplelist>
1095 </refsect1>
1096 </refentry>