aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/create_table.sgml
blob: b558731137a94c43f5f5d45cc6eb266c0c6c915d (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/create_table.sgml,v 1.72 2003/09/09 18:28:52 tgl Exp $
PostgreSQL documentation
-->

<refentry id="SQL-CREATETABLE">
 <refmeta>
  <refentrytitle id="sql-createtable-title">CREATE TABLE</refentrytitle>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>

 <refnamediv>
  <refname>CREATE TABLE</refname>
  <refpurpose>define a new table</refpurpose>
 </refnamediv>

 <indexterm zone="sql-createtable">
  <primary>CREATE TABLE</primary>
 </indexterm>

 <refsynopsisdiv>
<synopsis>
CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } ] TABLE <replaceable class="PARAMETER">table_name</replaceable> (
    { <replaceable class="PARAMETER">column_name</replaceable> <replaceable class="PARAMETER">data_type</replaceable> [ DEFAULT <replaceable>default_expr</> ] [ <replaceable class="PARAMETER">column_constraint</replaceable> [, ... ] ]
    | <replaceable>table_constraint</replaceable>
    | LIKE <replaceable>parent_table</replaceable> [ { INCLUDING | EXCLUDING } DEFAULTS ] }  [, ... ]
)
[ INHERITS ( <replaceable>parent_table</replaceable> [, ... ] ) ]
[ WITH OIDS | WITHOUT OIDS ]
[ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]

where <replaceable class="PARAMETER">column_constraint</replaceable> is:

[ CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable> ]
{ NOT NULL | NULL | UNIQUE | PRIMARY KEY |
  CHECK (<replaceable class="PARAMETER">expression</replaceable>) |
  REFERENCES <replaceable class="PARAMETER">reftable</replaceable> [ ( <replaceable class="PARAMETER">refcolumn</replaceable> ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ]
    [ ON DELETE <replaceable class="parameter">action</replaceable> ] [ ON UPDATE <replaceable class="parameter">action</replaceable> ] }
[ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]

and <replaceable class="PARAMETER">table_constraint</replaceable> is:

[ CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable> ]
{ UNIQUE ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] ) |
  PRIMARY KEY ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] ) |
  CHECK ( <replaceable class="PARAMETER">expression</replaceable> ) |
  FOREIGN KEY ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] ) REFERENCES <replaceable class="PARAMETER">reftable</replaceable> [ ( <replaceable class="PARAMETER">refcolumn</replaceable> [, ... ] ) ]
    [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ] [ ON DELETE <replaceable class="parameter">action</replaceable> ] [ ON UPDATE <replaceable class="parameter">action</replaceable> ] }
[ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
</synopsis>
  
 </refsynopsisdiv>

 <refsect1 id="SQL-CREATETABLE-description">
  <title>Description</title>

  <para>
   <command>CREATE TABLE</command> will create a new, initially empty table
   in the current database. The table will be owned by the user issuing the
   command.
  </para>

  <para>
   If a schema name is given (for example, <literal>CREATE TABLE
   myschema.mytable ...</>) then the table is created in the
   specified schema.  Otherwise it is created in the current schema.
   Temporary tables exist in a special schema, so a schema name may not be
   given when creating a temporary table.
   The table name must be distinct from the name of any other table,
   sequence, index, or view in the same schema.
  </para>

  <para>
   <command>CREATE TABLE</command> also automatically creates a data
   type that represents the composite type corresponding
   to one row of the table.  Therefore, tables cannot have the same
   name as any existing data type in the same schema.
  </para>

  <para>
   A table cannot have more than 1600 columns.  (In practice, the
   effective limit is lower because of tuple-length constraints).
  </para>

  <para>
   The optional constraint clauses specify constraints (or tests) that
   new or updated rows must satisfy for an insert or update operation
   to succeed.  A constraint is an SQL object that helps define the
   set of valid values in the table in various ways.
  </para>

  <para>
   There are two ways to define constraints: table constraints and
   column constraints.  A column constraint is defined as part of a
   column definition.  A table constraint definition is not tied to a
   particular column, and it can encompass more than one column.
   Every column constraint can also be written as a table constraint;
   a column constraint is only a notational convenience if the
   constraint only affects one column.
  </para>
 </refsect1>

 <refsect1>
  <title>Parameters</title>

  <variablelist>

   <varlistentry>
    <term><literal>TEMPORARY</> or <literal>TEMP</></term>
    <listitem>
     <para>
      If specified, the table is created as a temporary table.
      Temporary tables are automatically dropped at the end of a
      session, or optionally at the end of the current transaction 
      (see ON COMMIT below).  Existing permanent tables with the same 
      name are not visible to the current session while the temporary 
      table exists, unless they are referenced with schema-qualified 
      names. Any indexes created on a temporary table are automatically
      temporary as well.
     </para>

     <para>
      Optionally, <literal>GLOBAL</literal> or <literal>LOCAL</literal>
      can be written before <literal>TEMPORARY</> or <literal>TEMP</>.
      This makes no difference in <productname>PostgreSQL</>, but see
      <xref linkend="sql-createtable-compatibility"
      endterm="sql-createtable-compatibility-title">.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="PARAMETER">table_name</replaceable></term>
    <listitem>
     <para>
      The name (optionally schema-qualified) of the table to be created.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="PARAMETER">column_name</replaceable></term>
    <listitem>
     <para>
      The name of a column to be created in the new table.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="PARAMETER">data_type</replaceable></term>
    <listitem>
     <para>
      The data type of the column. This may include array specifiers.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>DEFAULT
    <replaceable>default_expr</replaceable></literal></term>
    <listitem>
     <para>
      The <literal>DEFAULT</> clause assigns a default data value for
      the column whose column definition it appears within.  The value
      is any variable-free expression (subqueries and cross-references
      to other columns in the current table are not allowed).  The
      data type of the default expression must match the data type of the
      column.
     </para>

     <para>
      The default expression will be used in any insert operation that
      does not specify a value for the column.  If there is no default
      for a column, then the default is null.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>LIKE <replaceable>parent_table</replaceable> [ { INCLUDING | EXCLUDING } DEFAULTS ]</literal></term>
    <listitem>
     <para>
      The <literal>LIKE</literal> clause specifies a table from which
      the new table automatically inherits all column names, their datatypes, and
      <literal>NOT NULL</literal> constraints.
     </para>
     <para>
      Unlike <literal>INHERITS</literal>, the new table and inherited table
      are complete decoupled after creation has been completed.  Data inserted
      into the new table will not be reflected into the parent table.
     </para>
     <para>
      Default expressions for the inherited column definitions will only be included if
      <literal>INCLUDING DEFAULTS</literal> is specified.  The default is to exclude
      default expressions.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>INHERITS ( <replaceable>parent_table</replaceable> [, ... ] )</literal></term>
    <listitem>
     <para>
      The optional <literal>INHERITS</> clause specifies a list of
      tables from which the new table automatically inherits all
      columns.  If the same column name exists in more than one parent
      table, an error is reported unless the data types of the columns
      match in each of the parent tables.  If there is no conflict,
      then the duplicate columns are merged to form a single column in
      the new table.  If the column name list of the new table
      contains a column that is also inherited, the data type must
      likewise match the inherited column(s), and the column
      definitions are merged into one.  However, inherited and new
      column declarations of the same name need not specify identical
      constraints: all constraints provided from any declaration are
      merged together and all are applied to the new table.  If the
      new table explicitly specifies a default value for the column,
      this default overrides any defaults from inherited declarations
      of the column.  Otherwise, any parents that specify default
      values for the column must all specify the same default, or an
      error will be reported.
     </para>
<!--
     <para>
      <productname>PostgreSQL</> automatically allows the
     created table to inherit
      functions on tables above it in the inheritance hierarchy; that
      is, if we create table <literal>foo</literal> inheriting from
      <literal>bar</literal>, then functions that accept the tuple
      type <literal>bar</literal> can also be applied to instances of
      <literal>foo</literal>.  (Currently, this works reliably for
      functions on the first or only parent table, but not so well for
      functions on additional parents.)
     </para>
-->
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>WITH OIDS</></term>
    <term><literal>WITHOUT OIDS</></term>
    <listitem>
     <para>
      This optional clause specifies whether rows of the new table
      should have OIDs (object identifiers) assigned to them.  The
      default is to have OIDs.  (If the new table inherits from any
      tables that have OIDs, then <literal>WITH OIDS</> is forced even
      if the command says <literal>WITHOUT OIDS</>.)
     </para>

     <para>
      Specifying <literal>WITHOUT OIDS</> allows the user to suppress
      generation of OIDs for rows of a table.  This may be worthwhile
      for large tables, since it will reduce OID consumption and
      thereby postpone wraparound of the 32-bit OID counter.  Once the
      counter wraps around, uniqueness of OIDs can no longer be
      assumed, which considerably reduces their usefulness. Specifying
      <literal>WITHOUT OIDS</literal> also reduces the space required
      to store the table on disk by 4 bytes per row of the table,
      thereby improving performance.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable></literal></term>
    <listitem>
     <para>
      An optional name for a column or table constraint.  If not specified,
      the system generates a name.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>NOT NULL</></term>
    <listitem>
     <para>
      The column is not allowed to contain null values.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>NULL</></term>
    <listitem>
     <para>
      The column is allowed to contain null values. This is the default.
     </para>

     <para>
      This clause is only available for compatibility with
      non-standard SQL databases.  Its use is discouraged in new
      applications.
     </para>
    </listitem>
   </varlistentry>
   
   <varlistentry>
    <term><literal>UNIQUE</> (column constraint)</term>
    <term><literal>UNIQUE ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] )</> (table constraint)</term>

    <listitem>
     <para>
      The <literal>UNIQUE</literal> constraint specifies that a
      group of one or more distinct columns of a table may contain
      only unique values. The behavior of the unique table constraint
      is the same as that for column constraints, with the additional
      capability to span multiple columns.
     </para>

     <para>
      For the purpose of a unique constraint, null values are not
      considered equal.
     </para>

     <para>
      Each unique table constraint must name a set of columns that is
      different from the set of columns named by any other unique or
      primary key constraint defined for the table.  (Otherwise it
      would just be the same constraint listed twice.)
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>PRIMARY KEY</> (column constraint)</term>
    <term><literal>PRIMARY KEY ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] )</> (table constraint)</term>
    <listitem>
     <para>
      The primary key constraint specifies that a column or columns of a table
      may contain only unique (non-duplicate), nonnull values.
      Technically, <literal>PRIMARY KEY</literal> is merely a
      combination of <literal>UNIQUE</> and <literal>NOT NULL</>, but
      identifying a set of columns as primary key also provides
      metadata about the design of the schema, as a primary key
      implies that other tables
      may rely on this set of columns as a unique identifier for rows.
     </para>

     <para>
      Only one primary key can be specified for a table, whether as a
      column constraint or a table constraint.
     </para>

     <para>
      The primary key constraint should name a set of columns that is
      different from other sets of columns named by any unique
      constraint defined for the same table.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>CHECK (<replaceable class="PARAMETER">expression</replaceable>)</literal></term>
    <listitem>
     <para>
      The <literal>CHECK</> clause specifies an expression producing a
      Boolean result which new or updated rows must satisfy for an
      insert or update operation to succeed.  A check constraint
      specified as a column constraint should reference that column's
      value only, while an expression appearing in a table constraint
      may reference multiple columns.
     </para>

     <para>
      Currently, <literal>CHECK</literal> expressions cannot contain
      subqueries nor refer to variables other than columns of the
      current row.
     </para>
    </listitem>
   </varlistentry>


   <varlistentry>
    <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>

   <term><literal>FOREIGN KEY ( <replaceable class="parameter">column</replaceable> [, ... ] )
    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>
    (table constraint)</term>

    <listitem>
     <para>
      Theses clauses specify a foreign key constraint, which specifies
      that a group of one or more columns of the new table must only
      contain values which match against values in the referenced
      column(s) <replaceable class="parameter">refcolumn</replaceable>
      of the referenced table <replaceable
      class="parameter">reftable</replaceable>.  If <replaceable
      class="parameter">refcolumn</replaceable> is omitted, the
      primary key of the <replaceable
      class="parameter">reftable</replaceable> is used.  The
      referenced columns must be the columns of a unique or primary
      key constraint in the referenced table.
     </para>

     <para>
      A value inserted into these columns is matched against the
      values of the referenced table and referenced columns using the
      given match type.  There are three match types: <literal>MATCH
      FULL</>, <literal>MATCH PARTIAL</>, and <literal>MATCH
      SIMPLE</literal>, which is also the default.  <literal>MATCH
      FULL</> will not allow one column of a multicolumn foreign key
      to be null unless all foreign key columns are null.
      <literal>MATCH SIMPLE</literal> allows some foreign key columns
      to be null while other parts of the foreign key are not
      null. <literal>MATCH PARTIAL</> is not yet implemented.
     </para>

     <para>
      In addition, when the data in the referenced columns is changed,
      certain actions are performed on the data in this table's
      columns.  The <literal>ON DELETE</literal> clause specifies the
      action to perform when a referenced row in the referenced table is
      being deleted.  Likewise, the <literal>ON UPDATE</literal>
      clause specifies the action to perform when a referenced column
      in the referenced table is being updated to a new value. If the
      row is updated, but the referenced column is not actually
      changed, no action is done.  There are the following possible
      actions for each clause:

      <variablelist>
       <varlistentry>
        <term><literal>NO ACTION</literal></term>
        <listitem>
         <para>
          Produce an error indicating that the deletion or update
          would create a foreign key constraint violation.  This is
          the default action.
         </para>
        </listitem>
       </varlistentry>

       <varlistentry>
        <term><literal>RESTRICT</literal></term>
        <listitem>
         <para>
          Same as <literal>NO ACTION</literal>.
         </para>
        </listitem>
       </varlistentry>

       <varlistentry>
        <term><literal>CASCADE</literal></term>
        <listitem>
         <para>
          Delete any rows referencing the deleted row, or update the
          value of the referencing column to the new value of the
          referenced column, respectively.
         </para>
        </listitem>
       </varlistentry>

       <varlistentry>
        <term><literal>SET NULL</literal></term>
        <listitem>
         <para>
          Set the referencing column values to null.
         </para>
        </listitem>
       </varlistentry>

       <varlistentry>
        <term><literal>SET DEFAULT</literal></term>
        <listitem>
         <para>
          Set the referencing column values to their default value.
         </para>
        </listitem>
       </varlistentry>
      </variablelist>
     </para>

     <para>
      If primary key column is updated frequently, it may be wise to
      add an index to the foreign key column so that <literal>NO
      ACTION</literal> and <literal>CASCADE</literal> actions
      associated with the foreign key column can be more efficiently
      performed.
     </para>
    </listitem>
   </varlistentry>
   
   <varlistentry>
    <term><literal>DEFERRABLE</literal></term>
    <term><literal>NOT DEFERRABLE</literal></term>
    <listitem>
     <para>
      This controls whether the constraint can be deferred.  A
      constraint that is not deferrable will be checked immediately
      after every command.  Checking of constraints that are
      deferrable may be postponed until the end of the transaction
      (using the <xref linkend="sql-set-constraints" endterm="sql-set-constraints-title"> command).
      <literal>NOT DEFERRABLE</literal> is the default.  Only foreign
      key constraints currently accept this clause.  All other
      constraint types are not deferrable.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>INITIALLY IMMEDIATE</literal></term>
    <term><literal>INITIALLY DEFERRED</literal></term>
    <listitem>
     <para>
      If a constraint is deferrable, this clause specifies the default
      time to check the constraint.  If the constraint is
      <literal>INITIALLY IMMEDIATE</literal>, it is checked after each
      statement. This is the default.  If the constraint is
      <literal>INITIALLY DEFERRED</literal>, it is checked only at the
      end of the transaction.  The constraint check time can be
      altered with the <xref linkend="sql-set-constraints" endterm="sql-set-constraints-title"> command.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>ON COMMIT</literal></term>
    <listitem>
     <para>
      The behavior of temporary tables at the end of a transaction
      block can be controlled using <literal>ON COMMIT</literal>. 
      The three options are:

      <variablelist>
       <varlistentry>
        <term><literal>PRESERVE ROWS</literal></term>
        <listitem>
         <para>
	  No special action is taken at the ends of transactions.
	  This is the default behavior.
         </para>
     	</listitem>
       </varlistentry>
           
       <varlistentry>
        <term><literal>DELETE ROWS</literal></term>
        <listitem>
         <para>
          All rows in the temporary table will be deleted at the
          end of each transaction block.  Essentially, an automatic
	  <xref linkend="sql-truncate"> is done at each commit.
         </para>
        </listitem>
       </varlistentry>

       <varlistentry>
        <term><literal>DROP</literal></term>
        <listitem>
         <para>
          The temporary table will be dropped at the end of the current
	  transaction block.
         </para>
        </listitem>
       </varlistentry>
      </variablelist>
     </para>
    </listitem>
   </varlistentry>
  </variablelist>
 </refsect1>    

 <refsect1 id="SQL-CREATETABLE-notes">
  <title>Notes</title>

  <itemizedlist>
   <listitem>
    <para>
     Whenever an application makes use of OIDs to identify specific
     rows of a table, it is recommended to create a unique constraint
     on the <structfield>oid</> column of that table, to ensure that
     OIDs in the table will indeed uniquely identify rows even after
     counter wraparound.  Avoid assuming that OIDs are unique across
     tables; if you need a database-wide unique identifier, use the
     combination of <structfield>tableoid</> and row OID for the
     purpose.  (It is likely that future <productname>PostgreSQL</>
     releases will use a separate OID counter for each table, so that
     it will be <emphasis>necessary</>, not optional, to include
     <structfield>tableoid</> to have a unique identifier
     database-wide.)
    </para>

    <tip>
     <para>
      The use of <literal>WITHOUT OIDS</literal> is not recommended
      for tables with no primary key, since without either an OID or a
      unique data key, it is difficult to identify specific rows.
     </para>
    </tip>
   </listitem>

   <listitem>
    <para>
     <productname>PostgreSQL</productname> automatically creates an
     index for each unique constraint and primary key constraint to
     enforce the uniqueness.  Thus, it is not necessary to create an
     explicit index for primary key columns.  (See <xref
     linkend="sql-createindex" endterm="sql-createindex-title"> for more information.)
    </para>
   </listitem>

   <listitem>
    <para>
     Unique constraints and primary keys are not inherited in the
     current implementation.  This makes the combination of
     inheritance and unique constraints rather dysfunctional.
    </para>
   </listitem>
  </itemizedlist>
 </refsect1>


 <refsect1 id="SQL-CREATETABLE-examples">
  <title>Examples</title>

  <para>
   Create table <structname>films</> and table
   <structname>distributors</>:

<programlisting>
CREATE TABLE films (
    code        char(5) CONSTRAINT firstkey PRIMARY KEY,
    title       varchar(40) NOT NULL,
    did         integer NOT NULL,
    date_prod   date,
    kind        varchar(10),
    len         interval hour to minute
);
</programlisting>

<programlisting>
CREATE TABLE distributors (
     did    integer PRIMARY KEY DEFAULT nextval('serial'),
     name   varchar(40) NOT NULL CHECK (name &lt;&gt; '')
);
</programlisting>
  </para>

  <para>
   Create a table with a 2-dimensional array:

<programlisting>
CREATE TABLE array (
    vector  int[][]
);
</programlisting>
  </para>

  <para>
   Define a unique table constraint for the table
   <literal>films</literal>.  Unique table constraints can be defined
   on one or more columns of the table.

<programlisting>
CREATE TABLE films (
    code        char(5),
    title       varchar(40),
    did         integer,
    date_prod   date,
    kind        varchar(10),
    len         interval hour to minute,
    CONSTRAINT production UNIQUE(date_prod)
);
</programlisting>
  </para>
  
  <para>
   Define a check column constraint:

<programlisting>
CREATE TABLE distributors (
    did     integer CHECK (did > 100),
    name    varchar(40)
);
</programlisting>
  </para>

  <para>
   Define a check table constraint:

<programlisting>
CREATE TABLE distributors (
    did     integer,
    name    varchar(40)
    CONSTRAINT con1 CHECK (did > 100 AND name &lt;&gt; '')
);
</programlisting>
  </para>
 
  <para>
   Define a primary key table constraint for the table
   <structname>films</>.  Primary key table constraints can be defined
   on one or more columns of the table.

<programlisting>
CREATE TABLE films (
    code        char(5),
    title       varchar(40),
    did         integer,
    date_prod   date,
    kind        varchar(10),
    len         interval hour to minute,
    CONSTRAINT code_title PRIMARY KEY(code,title)
);
</programlisting>
  </para>

  <para>
   Define a primary key constraint for table
   <structname>distributors</>.  The following two examples are
   equivalent, the first using the table constraint syntax, the second
   the column constraint notation.

<programlisting>
CREATE TABLE distributors (
    did     integer,
    name    varchar(40),
    PRIMARY KEY(did)
); 
</programlisting>

<programlisting>
CREATE TABLE distributors (
    did     integer PRIMARY KEY,
    name    varchar(40)
);
</programlisting>
  </para>

  <para>
   This assigns a literal constant default value for the column
   <literal>name</literal>, arranges for the default value of column
   <literal>did</literal> to be generated by selecting the next value
   of a sequence object, and makes the default value of
   <literal>modtime</literal> be the time at which the row is
   inserted.

<programlisting>
CREATE TABLE distributors (
    name      varchar(40) DEFAULT 'Luso Films',
    did       integer DEFAULT nextval('distributors_serial'),
    modtime   timestamp DEFAULT current_timestamp
);
</programlisting>
  </para>

  <para>
   Define two <literal>NOT NULL</> column constraints on the table
   <classname>distributors</classname>, one of which is explicitly
   given a name:

<programlisting>
CREATE TABLE distributors (
    did     integer CONSTRAINT no_null NOT NULL,
    name    varchar(40) NOT NULL
);
</programlisting>
    </para>

    <para>
     Define a unique constraint for the <literal>name</literal> column:

<programlisting>
CREATE TABLE distributors (
    did     integer,
    name    varchar(40) UNIQUE
);
</programlisting>

     The above is equivalent to the following specified as a table constraint:

<programlisting>
CREATE TABLE distributors (
    did     integer,
    name    varchar(40),
    UNIQUE(name)
);
</programlisting>
  </para>

 </refsect1>
 
 <refsect1 id="SQL-CREATETABLE-compatibility">
  <title id="SQL-CREATETABLE-compatibility-title">Compatibility</title>

  <para>
   The <command>CREATE TABLE</command> command conforms to SQL92
   and to a subset of SQL99, with exceptions listed below.
  </para>

  <refsect2>
   <title>Temporary Tables</title>

   <para>
    Although the syntax of <literal>CREATE TEMPORARY TABLE</literal>
    resembles that of the SQL standard, the effect is not the same.  In the
    standard, 
    temporary tables are defined just once and automatically exist (starting
    with empty contents) in every session that needs them.
    <productname>PostgreSQL</productname> instead
    requires each session to issue its own <literal>CREATE TEMPORARY
    TABLE</literal> command for each temporary table to be used.  This allows
    different sessions to use the same temporary table name for different
    purposes, whereas the standard's approach constrains all instances of a
    given temporary table name to have the same table structure.
   </para>

   <para>
    The standard's definition of the behavior of temporary tables is
    widely ignored.  <productname>PostgreSQL</productname>'s behavior
    on this point is similar to that of several other SQL databases.
   </para>

   <para>
    The standard's distinction between global and local temporary tables
    is not in <productname>PostgreSQL</productname>, since that distinction
    depends on the concept of modules, which
    <productname>PostgreSQL</productname> does not have.
    For compatibility's sake, <productname>PostgreSQL</productname> will
    accept the <literal>GLOBAL</literal> and <literal>LOCAL</literal> keywords
    in a temporary table declaration, but they have no effect.
   </para>

   <para>
    The <literal>ON COMMIT</literal> clause for temporary tables
    also resembles the SQL standard, but has some differences.
    If the <literal>ON COMMIT</> clause is omitted, SQL specifies that the
    default behavior is <literal>ON COMMIT DELETE ROWS</>.  However, the
    default behavior in <productname>PostgreSQL</productname> is
    <literal>ON COMMIT PRESERVE ROWS</literal>.  The <literal>ON COMMIT
    DROP</literal> option does not exist in SQL.
   </para>
  </refsect2>

  <refsect2>
   <title>Column Check Constraints</title>

   <para>
    The SQL standard says that <literal>CHECK</> column constraints
    may only refer to the column they apply to; only <literal>CHECK</>
    table constraints may refer to multiple columns.
    <productname>PostgreSQL</productname> does not enforce this
    restriction; it treats column and table check constraints alike.
   </para>
  </refsect2>

  <refsect2>
   <title><literal>NULL</literal> <quote>Constraint</quote></title>

   <para>
    The <literal>NULL</> <quote>constraint</quote> (actually a
    non-constraint) is a <productname>PostgreSQL</productname>
    extension to the SQL standard that is included for compatibility with some
    other database systems (and for symmetry with the <literal>NOT
    NULL</literal> constraint).  Since it is the default for any
    column, its presence is simply noise.
   </para>
  </refsect2>
   
  <refsect2>
   <title>Inheritance</title>

   <para>
    Multiple inheritance via the <literal>INHERITS</literal> clause is
    a <productname>PostgreSQL</productname> language extension.  SQL99
    (but not SQL92) defines single inheritance using a different
    syntax and different semantics.  SQL99-style inheritance is not
    yet supported by <productname>PostgreSQL</productname>.
   </para>
  </refsect2>

  <refsect2>
   <title>Object IDs</title>

   <para>
    The <productname>PostgreSQL</productname> concept of OIDs is not
    standard.
   </para>
  </refsect2>

  <refsect2>
   <title>Zero-column tables</title>

   <para>
    <productname>PostgreSQL</productname> allows a table of no columns
    to be created (for example, <literal>CREATE TABLE foo();</>).  This
    is an extension from the SQL standard, which does not allow zero-column
    tables.  Zero-column tables are not in themselves very useful, but
    disallowing them creates odd special cases for <command>ALTER TABLE
    DROP COLUMN</>, so it seems cleaner to ignore this spec restriction.
   </para>
  </refsect2>
 </refsect1>


 <refsect1>
  <title>See Also</title>

  <simplelist type="inline">
   <member><xref linkend="sql-altertable" endterm="sql-altertable-title"></member>
   <member><xref linkend="sql-droptable" endterm="sql-droptable-title"></member>
  </simplelist>
 </refsect1>
</refentry>

<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->