summaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/create_table.sgml
blob: a0c9a6d257182142107518230a342829fd5415fe (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
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
1330
1331
1332
1333
1334
1335
1336
1337
1338
1339
1340
1341
1342
1343
1344
1345
1346
1347
1348
1349
1350
1351
1352
1353
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
1426
1427
1428
1429
1430
1431
1432
1433
1434
1435
1436
1437
1438
1439
1440
1441
1442
1443
1444
1445
1446
1447
1448
1449
1450
1451
1452
1453
1454
1455
1456
1457
1458
1459
1460
1461
1462
1463
1464
1465
1466
1467
1468
1469
1470
1471
1472
1473
1474
1475
1476
1477
1478
1479
1480
1481
1482
1483
1484
1485
1486
1487
1488
1489
1490
1491
1492
1493
1494
1495
1496
1497
1498
1499
1500
1501
1502
1503
1504
1505
1506
1507
1508
1509
1510
1511
1512
1513
1514
1515
1516
1517
1518
1519
1520
1521
1522
1523
1524
1525
1526
1527
1528
1529
1530
1531
1532
1533
1534
1535
1536
1537
1538
1539
1540
1541
1542
1543
1544
1545
1546
1547
1548
1549
1550
1551
1552
1553
1554
1555
1556
1557
1558
1559
1560
1561
1562
1563
1564
1565
1566
1567
1568
1569
1570
1571
1572
1573
1574
1575
1576
1577
1578
1579
1580
1581
1582
1583
1584
1585
1586
1587
1588
1589
1590
1591
1592
1593
1594
1595
1596
1597
1598
1599
1600
1601
1602
1603
1604
1605
1606
1607
1608
1609
1610
1611
1612
1613
1614
1615
1616
1617
1618
1619
1620
1621
1622
1623
1624
1625
1626
1627
1628
1629
1630
1631
1632
1633
1634
1635
1636
1637
1638
1639
1640
1641
1642
1643
1644
1645
1646
1647
1648
1649
1650
1651
1652
1653
1654
1655
1656
1657
1658
1659
1660
1661
1662
1663
1664
1665
1666
1667
1668
1669
1670
1671
1672
1673
1674
1675
1676
1677
1678
1679
1680
1681
1682
1683
1684
1685
1686
1687
1688
1689
1690
1691
1692
1693
1694
1695
1696
1697
1698
1699
1700
1701
1702
1703
1704
1705
1706
1707
1708
1709
1710
1711
1712
1713
1714
1715
1716
1717
1718
1719
1720
1721
1722
1723
1724
1725
1726
1727
1728
1729
1730
1731
1732
1733
1734
1735
1736
1737
1738
1739
1740
1741
1742
1743
1744
1745
1746
1747
1748
1749
1750
1751
1752
1753
1754
1755
1756
1757
1758
1759
1760
1761
1762
1763
1764
1765
1766
1767
1768
1769
1770
1771
1772
1773
1774
1775
1776
1777
1778
1779
1780
1781
1782
1783
1784
1785
1786
1787
1788
1789
1790
1791
1792
1793
1794
1795
1796
1797
1798
1799
1800
1801
1802
1803
1804
1805
1806
1807
1808
1809
1810
1811
1812
1813
1814
1815
1816
1817
1818
1819
1820
1821
1822
1823
1824
1825
1826
1827
1828
1829
1830
1831
1832
1833
1834
1835
1836
1837
1838
1839
1840
1841
1842
1843
1844
1845
1846
1847
1848
1849
1850
1851
1852
1853
1854
1855
1856
1857
1858
1859
1860
1861
1862
1863
1864
1865
1866
1867
1868
1869
1870
1871
1872
1873
1874
1875
1876
1877
1878
1879
1880
1881
1882
1883
1884
1885
1886
1887
1888
1889
1890
1891
1892
1893
1894
1895
1896
1897
1898
1899
1900
1901
1902
1903
1904
1905
1906
1907
1908
1909
1910
1911
1912
1913
1914
1915
1916
1917
1918
1919
1920
1921
1922
1923
1924
1925
1926
1927
1928
1929
1930
1931
1932
1933
1934
1935
1936
1937
1938
1939
1940
1941
1942
1943
1944
1945
1946
1947
1948
1949
1950
1951
1952
1953
1954
1955
1956
1957
1958
1959
1960
1961
1962
1963
1964
1965
1966
1967
1968
1969
1970
1971
1972
1973
1974
1975
1976
1977
1978
1979
1980
1981
1982
1983
1984
1985
1986
1987
1988
1989
1990
1991
1992
1993
1994
1995
1996
1997
1998
1999
2000
2001
2002
2003
2004
2005
2006
2007
2008
2009
2010
2011
2012
2013
2014
2015
2016
<!--
doc/src/sgml/ref/create_table.sgml
PostgreSQL documentation
-->

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

 <refmeta>
  <refentrytitle>CREATE TABLE</refentrytitle>
  <manvolnum>7</manvolnum>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>

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

 <refsynopsisdiv>
<synopsis>
CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXISTS ] <replaceable class="parameter">table_name</replaceable> ( [
  { <replaceable class="parameter">column_name</replaceable> <replaceable class="parameter">data_type</replaceable> [ COLLATE <replaceable>collation</replaceable> ] [ <replaceable class="parameter">column_constraint</replaceable> [ ... ] ]
    | <replaceable>table_constraint</replaceable>
    | LIKE <replaceable>source_table</replaceable> [ <replaceable>like_option</replaceable> ... ] }
    [, ... ]
] )
[ INHERITS ( <replaceable>parent_table</replaceable> [, ... ] ) ]
[ 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> ] [, ... ] ) ]
[ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) | WITH OIDS | WITHOUT OIDS ]
[ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
[ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]

CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXISTS ] <replaceable class="parameter">table_name</replaceable>
    OF <replaceable class="parameter">type_name</replaceable> [ (
  { <replaceable class="parameter">column_name</replaceable> [ WITH OPTIONS ] [ <replaceable class="parameter">column_constraint</replaceable> [ ... ] ]
    | <replaceable>table_constraint</replaceable> }
    [, ... ]
) ]
[ 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> ] [, ... ] ) ]
[ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) | WITH OIDS | WITHOUT OIDS ]
[ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
[ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]

CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXISTS ] <replaceable class="parameter">table_name</replaceable>
    PARTITION OF <replaceable class="parameter">parent_table</replaceable> [ (
  { <replaceable class="parameter">column_name</replaceable> [ WITH OPTIONS ] [ <replaceable class="parameter">column_constraint</replaceable> [ ... ] ]
    | <replaceable>table_constraint</replaceable> }
    [, ... ]
) ] { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }
[ 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> ] [, ... ] ) ]
[ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) | WITH OIDS | WITHOUT OIDS ]
[ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
[ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]

<phrase>where <replaceable class="parameter">column_constraint</replaceable> is:</phrase>

[ CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> ]
{ NOT NULL |
  NULL |
  CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
  DEFAULT <replaceable>default_expr</replaceable> |
  GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( <replaceable>sequence_options</replaceable> ) ] |
  UNIQUE <replaceable class="parameter">index_parameters</replaceable> |
  PRIMARY KEY <replaceable class="parameter">index_parameters</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 ]

<phrase>and <replaceable class="parameter">table_constraint</replaceable> is:</phrase>

[ CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> ]
{ CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
  UNIQUE ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) <replaceable class="parameter">index_parameters</replaceable> |
  PRIMARY KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) <replaceable class="parameter">index_parameters</replaceable> |
  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> ) ] |
  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 ]

<phrase>and <replaceable class="parameter">like_option</replaceable> is:</phrase>

{ INCLUDING | EXCLUDING } { DEFAULTS | CONSTRAINTS | IDENTITY | INDEXES | STORAGE | COMMENTS | ALL }

<phrase>and <replaceable class="parameter">partition_bound_spec</replaceable> is:</phrase>

IN ( { <replaceable class="parameter">numeric_literal</replaceable> | <replaceable class="parameter">string_literal</replaceable> | NULL } [, ...] ) |
FROM ( { <replaceable class="parameter">numeric_literal</replaceable> | <replaceable class="parameter">string_literal</replaceable> | MINVALUE | MAXVALUE } [, ...] )
  TO ( { <replaceable class="parameter">numeric_literal</replaceable> | <replaceable class="parameter">string_literal</replaceable> | MINVALUE | MAXVALUE } [, ...] ) |
WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REMAINDER <replaceable class="parameter">numeric_literal</replaceable> )

<phrase><replaceable class="parameter">index_parameters</replaceable> in <literal>UNIQUE</literal>, <literal>PRIMARY KEY</literal>, and <literal>EXCLUDE</literal> constraints are:</phrase>

[ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
[ USING INDEX TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]

<phrase><replaceable class="parameter">exclude_element</replaceable> in an <literal>EXCLUDE</literal> constraint is:</phrase>

{ <replaceable class="parameter">column_name</replaceable> | ( <replaceable class="parameter">expression</replaceable> ) } [ <replaceable class="parameter">opclass</replaceable> ] [ ASC | DESC ] [ NULLS { FIRST | LAST } ]
</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 ...</literal>) 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 cannot be given
   when creating a temporary table.  The name of the table must be
   distinct from the name of any other table, sequence, index, view,
   or foreign table 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>
   The optional constraint clauses specify constraints (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 for use when the
   constraint only affects one column.
  </para>

  <para>
   To be able to create a table, you must have <literal>USAGE</literal>
   privilege on all column types or the type in the <literal>OF</literal>
   clause, respectively.
  </para>
 </refsect1>

 <refsect1>
  <title>Parameters</title>

  <variablelist>

   <varlistentry id="sql-createtable-temporary">
    <term><literal>TEMPORARY</literal> or <literal>TEMP</literal></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 <literal>ON COMMIT</literal> 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>
      The <link linkend="autovacuum">autovacuum daemon</link> cannot
      access and therefore cannot vacuum or analyze temporary tables.
      For this reason, appropriate vacuum and analyze operations should be
      performed via session SQL commands.  For example, if a temporary
      table is going to be used in complex queries, it is wise to run
      <command>ANALYZE</command> on the temporary table after it is populated.
     </para>

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

   <varlistentry id="sql-createtable-unlogged">
    <term><literal>UNLOGGED</literal></term>
    <listitem>
     <para>
      If specified, the table is created as an unlogged table.  Data written
      to unlogged tables is not written to the write-ahead log (see <xref
      linkend="wal"/>), which makes them considerably faster than ordinary
      tables.  However, they are not crash-safe: an unlogged table is
      automatically truncated after a crash or unclean shutdown.  The contents
      of an unlogged table are also not replicated to standby servers.
      Any indexes created on an unlogged table are automatically unlogged as
      well.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>IF NOT EXISTS</literal></term>
    <listitem>
     <para>
      Do not throw an error if a relation with the same name already exists.
      A notice is issued in this case.  Note that there is no guarantee that
      the existing relation is anything like the one that would have been
      created.
     </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><literal>OF <replaceable class="parameter">type_name</replaceable></literal></term>
    <listitem>
     <para>
      Creates a <firstterm>typed table</firstterm>, which takes its
      structure from the specified composite type (name optionally
      schema-qualified).  A typed table is tied to its type; for
      example the table will be dropped if the type is dropped
      (with <literal>DROP TYPE ... CASCADE</literal>).
     </para>

     <para>
      When a typed table is created, then the data types of the
      columns are determined by the underlying composite type and are
      not specified by the <literal>CREATE TABLE</literal> command.
      But the <literal>CREATE TABLE</literal> command can add defaults
      and constraints to the table and can specify storage parameters.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry id="sql-createtable-partition">
    <term><literal>PARTITION OF <replaceable class="parameter">parent_table</replaceable> { FOR VALUES <replaceable class="parameter">partition_bound_spec</replaceable> | DEFAULT }</literal></term>
    <listitem>
     <para>
      Creates the table as a <firstterm>partition</firstterm> of the specified
      parent table. The table can be created either as a partition for specific
      values using <literal>FOR VALUES</literal> or as a default partition
      using <literal>DEFAULT</literal>.  This option is not available for
      hash-partitioned tables.
     </para>

     <para>
      The <replaceable class="parameter">partition_bound_spec</replaceable>
      must correspond to the partitioning method and partition key of the
      parent table, and must not overlap with any existing partition of that
      parent.  The form with <literal>IN</literal> is used for list partitioning,
      the form with <literal>FROM</literal> and <literal>TO</literal> is used
      for range partitioning, and the form with <literal>WITH</literal> is used
      for hash partitioning.
     </para>

     <para>
      Each of the values specified in
      the <replaceable class="parameter">partition_bound_spec</replaceable> is
      a literal, <literal>NULL</literal>, <literal>MINVALUE</literal>, or
      <literal>MAXVALUE</literal>.  Each literal value must be either a
      numeric constant that is coercible to the corresponding partition key
      column's type, or a string literal that is valid input for that type.
     </para>

     <para>
      When creating a list partition, <literal>NULL</literal> can be
      specified to signify that the partition allows the partition key
      column to be null.  However, there cannot be more than one such
      list partition for a given parent table.  <literal>NULL</literal>
      cannot be specified for range partitions.
     </para>

     <para>
      When creating a range partition, the lower bound specified with
      <literal>FROM</literal> is an inclusive bound, whereas the upper
      bound specified with <literal>TO</literal> is an exclusive bound.
      That is, the values specified in the <literal>FROM</literal> list
      are valid values of the corresponding partition key columns for this
      partition, whereas those in the <literal>TO</literal> list are
      not.  Note that this statement must be understood according to the
      rules of row-wise comparison (<xref linkend="row-wise-comparison"/>).
      For example, given <literal>PARTITION BY RANGE (x,y)</literal>, a partition
      bound <literal>FROM (1, 2) TO (3, 4)</literal>
      allows <literal>x=1</literal> with any <literal>y&gt;=2</literal>,
      <literal>x=2</literal> with any non-null <literal>y</literal>,
      and <literal>x=3</literal> with any <literal>y&lt;4</literal>.
     </para>

     <para>
      The special values <literal>MINVALUE</literal> and <literal>MAXVALUE</literal>
      may be used when creating a range partition to indicate that there
      is no lower or upper bound on the column's value. For example, a
      partition defined using <literal>FROM (MINVALUE) TO (10)</literal> allows
      any values less than 10, and a partition defined using
      <literal>FROM (10) TO (MAXVALUE)</literal> allows any values greater than
      or equal to 10.
     </para>

     <para>
      When creating a range partition involving more than one column, it
      can also make sense to use <literal>MAXVALUE</literal> as part of the lower
      bound, and <literal>MINVALUE</literal> as part of the upper bound. For
      example, a partition defined using
      <literal>FROM (0, MAXVALUE) TO (10, MAXVALUE)</literal> allows any rows
      where the first partition key column is greater than 0 and less than
      or equal to 10. Similarly, a partition defined using
      <literal>FROM ('a', MINVALUE) TO ('b', MINVALUE)</literal> allows any rows
      where the first partition key column starts with "a".
     </para>

     <para>
      Note that if <literal>MINVALUE</literal> or <literal>MAXVALUE</literal> is used for
      one column of a partitioning bound, the same value must be used for all
      subsequent columns.  For example, <literal>(10, MINVALUE, 0)</literal> is not
      a valid bound; you should write <literal>(10, MINVALUE, MINVALUE)</literal>.
     </para>

     <para>
      Also note that some element types, such as <literal>timestamp</literal>,
      have a notion of "infinity", which is just another value that can
      be stored. This is different from <literal>MINVALUE</literal> and
      <literal>MAXVALUE</literal>, which are not real values that can be stored,
      but rather they are ways of saying that the value is unbounded.
      <literal>MAXVALUE</literal> can be thought of as being greater than any
      other value, including "infinity" and <literal>MINVALUE</literal> as being
      less than any other value, including "minus infinity". Thus the range
      <literal>FROM ('infinity') TO (MAXVALUE)</literal> is not an empty range; it
      allows precisely one value to be stored &mdash; "infinity".
     </para>

     <para>
      If <literal>DEFAULT</literal> is specified, the table will be
      created as a default partition of the parent table. The parent can
      either be a list or range partitioned table. A partition key value
      not fitting into any other partition of the given parent will be
      routed to the default partition. There can be only one default
      partition for a given parent table.
     </para>

     <para>
      When a table has an existing <literal>DEFAULT</literal> partition and
      a new partition is added to it, the existing default partition must
      be scanned to verify that it does not contain any rows which properly
      belong in the new partition.  If the default partition contains a
      large number of rows, this may be slow.  The scan will be skipped if
      the default partition is a foreign table or if it has a constraint which
      proves that it cannot contain rows which should be placed in the new
      partition.
     </para>

     <para>
      When creating a hash partition, a modulus and remainder must be specified.
      The modulus must be a positive integer, and the remainder must be a
      non-negative integer less than the modulus.  Typically, when initially
      setting up a hash-partitioned table, you should choose a modulus equal to
      the number of partitions and assign every table the same modulus and a
      different remainder (see examples, below).   However, it is not required
      that every partition have the same modulus, only that every modulus which
      occurs among the partitions of a hash-partitioned table is a factor of the
      next larger modulus.  This allows the number of partitions to be increased
      incrementally without needing to move all the data at once.  For example,
      suppose you have a hash-partitioned table with 8 partitions, each of which
      has modulus 8, but find it necessary to increase the number of partitions
      to 16.  You can detach one of the modulus-8 partitions, create two new
      modulus-16 partitions covering the same portion of the key space (one with
      a remainder equal to the remainder of the detached partition, and the
      other with a remainder equal to that value plus 8), and repopulate them
      with data.  You can then repeat this -- perhaps at a later time -- for
      each modulus-8 partition until none remain.  While this may still involve
      a large amount of data movement at each step, it is still better than
      having to create a whole new table and move all the data at once.
     </para>

     <para>
      A partition must have the same column names and types as the partitioned
      table to which it belongs.  If the parent is specified <literal>WITH
      OIDS</literal> then all partitions must have OIDs; the parent's OID
      column will be inherited by all partitions just like any other column.
      Modifications to the column names or types of a partitioned table, or
      the addition or removal of an OID column, will automatically propagate
      to all partitions.  <literal>CHECK</literal> constraints will be inherited
      automatically by every partition, but an individual partition may specify
      additional <literal>CHECK</literal> constraints; additional constraints with
      the same name and condition as in the parent will be merged with the
      parent constraint.  Defaults may be specified separately for each
      partition.
     </para>

     <para>
      Rows inserted into a partitioned table will be automatically routed to
      the correct partition.  If no suitable partition exists, an error will
      occur.  Also, if updating a row in a given partition would require it
      to move to another partition due to new partition key values, an error
      will occur.
     </para>

     <para>
      Operations such as TRUNCATE which normally affect a table and all of its
      inheritance children will cascade to all partitions, but may also be
      performed on an individual partition.  Note that dropping a partition
      with <literal>DROP TABLE</literal> requires taking an <literal>ACCESS
      EXCLUSIVE</literal> lock on the parent table.
     </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 can include array
      specifiers. For more information on the data types supported by
      <productname>PostgreSQL</productname>, refer to <xref
      linkend="datatype"/>.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>COLLATE <replaceable>collation</replaceable></literal></term>
    <listitem>
     <para>
      The <literal>COLLATE</literal> clause assigns a collation to
      the column (which must be of a collatable data type).
      If not specified, the column data type's default collation is used.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>INHERITS ( <replaceable>parent_table</replaceable> [, ... ] )</literal></term>
    <listitem>
     <para>
      The optional <literal>INHERITS</literal> clause specifies a list of
      tables from which the new table automatically inherits all
      columns.  Parent tables can be plain tables or foreign tables.
     </para>

     <para>
      Use of <literal>INHERITS</literal> creates a persistent relationship
      between the new child table and its parent table(s).  Schema
      modifications to the parent(s) normally propagate to children
      as well, and by default the data of the child table is included in
      scans of the parent(s).
     </para>

     <para>
      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 name that is also inherited, the data type must
      likewise match the inherited column(s), and the column
      definitions are merged into one.  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>
      <literal>CHECK</literal> constraints are merged in essentially the same way as
      columns: if multiple parent tables and/or the new table definition
      contain identically-named <literal>CHECK</literal> constraints, these
      constraints must all have the same check expression, or an error will be
      reported.  Constraints having the same name and expression will
      be merged into one copy.  A constraint marked <literal>NO INHERIT</literal> in a
      parent will not be considered.  Notice that an unnamed <literal>CHECK</literal>
      constraint in the new table will never be merged, since a unique name
      will always be chosen for it.
     </para>

     <para>
      Column <literal>STORAGE</literal> settings are also copied from parent tables.
     </para>

     <para>
      If a column in the parent table is an identity column, that property is
      not inherited.  A column in the child table can be declared identity
      column if desired.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <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>
    <listitem>
     <para>
      The optional <literal>PARTITION BY</literal> clause specifies a strategy
      of partitioning the table.  The table thus created is called a
      <firstterm>partitioned</firstterm> table.  The parenthesized list of
      columns or expressions forms the <firstterm>partition key</firstterm>
      for the table.  When using range or hash partitioning, the partition key
      can include multiple columns or expressions (up to 32, but this limit can
      be altered when building <productname>PostgreSQL</productname>), but for
      list partitioning, the partition key must consist of a single column or
      expression.
     </para>

     <para>
      Range and list partitioning require a btree operator class, while hash
      partitioning requires a hash operator class.  If no operator class is
      specified explicitly, the default operator class of the appropriate
      type will be used; if no default operator class exists, an error will
      be raised.  When hash partitioning is used, the operator class used
      must implement support function 2 (see <xref linkend="xindex-support"/>
      for details).
     </para>

     <para>
      A partitioned table is divided into sub-tables (called partitions),
      which are created using separate <literal>CREATE TABLE</literal> commands.
      The partitioned table is itself empty.  A data row inserted into the
      table is routed to a partition based on the value of columns or
      expressions in the partition key.  If no existing partition matches
      the values in the new row, an error will be reported.
     </para>

     <para>
      Partitioned tables do not support <literal>UNIQUE</literal>,
      <literal>PRIMARY KEY</literal>, <literal>EXCLUDE</literal>, or
      <literal>FOREIGN KEY</literal> constraints; however, you can define
      these constraints on individual partitions.
     </para>

    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>LIKE <replaceable>source_table</replaceable> [ <replaceable>like_option</replaceable> ... ]</literal></term>
    <listitem>
     <para>
      The <literal>LIKE</literal> clause specifies a table from which
      the new table automatically copies all column names, their data types,
      and their not-null constraints.
     </para>
     <para>
      Unlike <literal>INHERITS</literal>, the new table and original table
      are completely decoupled after creation is complete.  Changes to the
      original table will not be applied to the new table, and it is not
      possible to include data of the new table in scans of the original
      table.
     </para>
     <para>
      Default expressions for the copied column definitions will be copied
      only if <literal>INCLUDING DEFAULTS</literal> is specified.  The
      default behavior is to exclude default expressions, resulting in the
      copied columns in the new table having null defaults.
      Note that copying defaults that call database-modification functions,
      such as <function>nextval</function>, may create a functional linkage between
      the original and new tables.
     </para>
     <para>
      Any identity specifications of copied column definitions will only be
      copied if <literal>INCLUDING IDENTITY</literal> is specified.  A new
      sequence is created for each identity column of the new table, separate
      from the sequences associated with the old table.
     </para>
     <para>
      Not-null constraints are always copied to the new table.
      <literal>CHECK</literal> constraints will be copied only if
      <literal>INCLUDING CONSTRAINTS</literal> is specified.
      No distinction is made between column constraints and table
      constraints.
     </para>
     <para>
      Indexes, <literal>PRIMARY KEY</literal>, <literal>UNIQUE</literal>,
      and <literal>EXCLUDE</literal> constraints on the original table will be
      created on the new table only if <literal>INCLUDING INDEXES</literal>
      is specified.  Names for the new indexes and constraints are
      chosen according to the default rules, regardless of how the originals
      were named.  (This behavior avoids possible duplicate-name failures for
      the new indexes.)
     </para>
     <para>
      <literal>STORAGE</literal> settings for the copied column definitions will be
      copied only if <literal>INCLUDING STORAGE</literal> is specified.  The
      default behavior is to exclude <literal>STORAGE</literal> settings, resulting
      in the copied columns in the new table having type-specific default
      settings.  For more on <literal>STORAGE</literal> settings, see
      <xref linkend="storage-toast"/>.
     </para>
     <para>
      Comments for the copied columns, constraints, and indexes
      will be copied only if <literal>INCLUDING COMMENTS</literal>
      is specified. The default behavior is to exclude comments, resulting in
      the copied columns and constraints in the new table having no comments.
     </para>
     <para>
      <literal>INCLUDING ALL</literal> is an abbreviated form of
      <literal>INCLUDING DEFAULTS INCLUDING IDENTITY INCLUDING CONSTRAINTS INCLUDING INDEXES INCLUDING STORAGE INCLUDING COMMENTS</literal>.
     </para>
     <para>
      Note that unlike <literal>INHERITS</literal>, columns and
      constraints copied by <literal>LIKE</literal> are not merged with similarly
      named columns and constraints.
      If the same name is specified explicitly or in another
      <literal>LIKE</literal> clause, an error is signaled.
     </para>
     <para>
      The <literal>LIKE</literal> clause can also be used to copy column
      definitions from views, foreign tables, or composite types.
      Inapplicable options (e.g., <literal>INCLUDING INDEXES</literal> from
      a view) are ignored.
     </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 the
      constraint is violated, the constraint name is present in error messages,
      so constraint names like <literal>col must be positive</literal> can be used
      to communicate helpful constraint information to client applications.
      (Double-quotes are needed to specify constraint names that contain spaces.)
      If a constraint name is not specified, the system generates a name.
     </para>
    </listitem>
   </varlistentry>

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

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

     <para>
      This clause is only provided for compatibility with
      non-standard SQL databases.  Its use is discouraged in new
      applications.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] </literal></term>
    <listitem>
     <para>
      The <literal>CHECK</literal> clause specifies an expression producing a
      Boolean result which new or updated rows must satisfy for an
      insert or update operation to succeed.  Expressions evaluating
      to TRUE or UNKNOWN succeed.  Should any row of an insert or
      update operation produce a FALSE result, an error exception is
      raised and the insert or update does not alter the database.  A
      check constraint specified as a column constraint should
      reference that column's value only, while an expression
      appearing in a table constraint can reference multiple columns.
     </para>

     <para>
      Currently, <literal>CHECK</literal> expressions cannot contain
      subqueries nor refer to variables other than columns of the
      current row.  The system column <literal>tableoid</literal>
      may be referenced, but not any other system column.
     </para>

     <para>
      A constraint marked with <literal>NO INHERIT</literal> will not propagate to
      child tables.
     </para>

     <para>
      When a table has multiple <literal>CHECK</literal> constraints,
      they will be tested for each row in alphabetical order by name,
      after checking <literal>NOT NULL</literal> constraints.
      (<productname>PostgreSQL</productname> versions before 9.5 did not honor any
      particular firing order for <literal>CHECK</literal> constraints.)
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>DEFAULT
    <replaceable>default_expr</replaceable></literal></term>
    <listitem>
     <para>
      The <literal>DEFAULT</literal> 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>GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( <replaceable>sequence_options</replaceable> ) ]</literal></term>
    <listitem>
     <para>
      This clause creates the column as an <firstterm>identity
      column</firstterm>.  It will have an implicit sequence attached to it
      and the column in new rows will automatically have values from the
      sequence assigned to it.
     </para>

     <para>
      The clauses <literal>ALWAYS</literal> and <literal>BY DEFAULT</literal>
      determine how the sequence value is given precedence over a
      user-specified value in an <command>INSERT</command> statement.
      If <literal>ALWAYS</literal> is specified, a user-specified value is
      only accepted if the <command>INSERT</command> statement
      specifies <literal>OVERRIDING SYSTEM VALUE</literal>.  If <literal>BY
      DEFAULT</literal> is specified, then the user-specified value takes
      precedence.  See <xref linkend="sql-insert"/> for details.  (In
      the <command>COPY</command> command, user-specified values are always
      used regardless of this setting.)
     </para>

     <para>
      The optional <replaceable>sequence_options</replaceable> clause can be
      used to override the options of the sequence.
      See <xref linkend="sql-createsequence"/> for details.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>UNIQUE</literal> (column constraint)</term>
    <term><literal>UNIQUE ( <replaceable class="parameter">column_name</replaceable> [, ... ] )</literal> (table constraint)</term>

    <listitem>
     <para>
      The <literal>UNIQUE</literal> constraint specifies that a
      group of one or more columns of a table can 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</literal> (column constraint)</term>
    <term><literal>PRIMARY KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] )</literal> (table constraint)</term>
    <listitem>
     <para>
      The <literal>PRIMARY KEY</literal> constraint specifies that a column or
      columns of a table can contain only unique (non-duplicate), nonnull
      values. 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 the set of columns named by any unique
      constraint defined for the same table.  (Otherwise, the unique
      constraint is redundant and will be discarded.)
     </para>

     <para>
      <literal>PRIMARY KEY</literal> enforces the same data constraints as
      a combination of <literal>UNIQUE</literal> and <literal>NOT NULL</literal>, but
      identifying a set of columns as the primary key also provides metadata
      about the design of the schema, since a primary key implies that other
      tables can rely on this set of columns as a unique identifier for rows.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry id="sql-createtable-exclude">
    <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>
    <listitem>
     <para>
      The <literal>EXCLUDE</literal> clause defines an exclusion
      constraint, which guarantees that if
      any two rows are compared on the specified column(s) or
      expression(s) using the specified operator(s), not all of these
      comparisons will return <literal>TRUE</literal>.  If all of the
      specified operators test for equality, this is equivalent to a
      <literal>UNIQUE</literal> constraint, although an ordinary unique constraint
      will be faster.  However, exclusion constraints can specify
      constraints that are more general than simple equality.
      For example, you can specify a constraint that
      no two rows in the table contain overlapping circles
      (see <xref linkend="datatype-geometric"/>) by using the
      <literal>&amp;&amp;</literal> operator.
     </para>

     <para>
      Exclusion constraints are implemented using
      an index, so each specified operator must be associated with an
      appropriate operator class
      (see <xref linkend="indexes-opclass"/>) for the index access
      method <replaceable>index_method</replaceable>.
      The operators are required to be commutative.
      Each <replaceable class="parameter">exclude_element</replaceable>
      can optionally specify an operator class and/or ordering options;
      these are described fully under
      <xref linkend="sql-createindex"/>.
     </para>

     <para>
      The access method must support <literal>amgettuple</literal> (see <xref
      linkend="indexam"/>); at present this means <acronym>GIN</acronym>
      cannot be used.  Although it's allowed, there is little point in using
      B-tree or hash indexes with an exclusion constraint, because this
      does nothing that an ordinary unique constraint doesn't do better.
      So in practice the access method will always be <acronym>GiST</acronym> or
      <acronym>SP-GiST</acronym>.
     </para>

     <para>
      The <replaceable class="parameter">predicate</replaceable> allows you to specify an
      exclusion constraint on a subset of the table; internally this creates a
      partial index. Note that parentheses are required around the predicate.
     </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_name</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>
      These clauses specify a foreign key constraint, which requires
      that a group of one or more columns of the new table must only
      contain values that match values in the referenced
      column(s) of some row of the referenced table.  If the <replaceable
      class="parameter">refcolumn</replaceable> list is omitted, the
      primary key of the <replaceable class="parameter">reftable</replaceable>
      is used.  The referenced columns must be the columns of a non-deferrable
      unique or primary key constraint in the referenced table.  The user
      must have <literal>REFERENCES</literal> permission on the referenced table
      (either the whole table, or the specific referenced columns).
      Note that foreign key constraints cannot be defined between temporary
      tables and permanent tables.
     </para>

     <para>
      A value inserted into the referencing column(s) 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>, <literal>MATCH PARTIAL</literal>, and <literal>MATCH
      SIMPLE</literal> (which is the default).  <literal>MATCH
      FULL</literal> will not allow one column of a multicolumn foreign key
      to be null unless all foreign key columns are null; if they are all
      null, the row is not required to have a match in the referenced table.
      <literal>MATCH SIMPLE</literal> allows any of the foreign key columns
      to be null; if any of them are null, the row is not required to have a
      match in the referenced table.
      <literal>MATCH PARTIAL</literal> is not yet implemented.
      (Of course, <literal>NOT NULL</literal> constraints can be applied to the
      referencing column(s) to prevent these cases from arising.)
     </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. Referential actions other than the
      <literal>NO ACTION</literal> check cannot be deferred, even if
      the constraint is declared deferrable. 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.
          If the constraint is deferred, this
          error will be produced at constraint check time if there still
          exist any referencing rows.  This is the default action.
         </para>
        </listitem>
       </varlistentry>

       <varlistentry>
        <term><literal>RESTRICT</literal></term>
        <listitem>
         <para>
          Produce an error indicating that the deletion or update
          would create a foreign key constraint violation.
          This is the same as <literal>NO ACTION</literal> except that
          the check is not deferrable.
         </para>
        </listitem>
       </varlistentry>

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

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

       <varlistentry>
        <term><literal>SET DEFAULT</literal></term>
        <listitem>
         <para>
          Set the referencing column(s) to their default values.
          (There must be a row in the referenced table matching the default
          values, if they are not null, or the operation will fail.)
         </para>
        </listitem>
       </varlistentry>
      </variablelist>
     </para>

     <para>
      If the referenced column(s) are changed frequently, it might be wise to
      add an index to the referencing column(s) so that referential actions
      associated with the foreign key constraint can be performed more
      efficiently.
     </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 can be postponed until the end of the transaction
      (using the <xref linkend="sql-set-constraints"/> command).
      <literal>NOT DEFERRABLE</literal> is the default.
      Currently, only <literal>UNIQUE</literal>, <literal>PRIMARY KEY</literal>,
      <literal>EXCLUDE</literal>, and
      <literal>REFERENCES</literal> (foreign key) constraints accept this
      clause.  <literal>NOT NULL</literal> and <literal>CHECK</literal> constraints are not
      deferrable.  Note that deferrable constraints cannot be used as
      conflict arbitrators in an <command>INSERT</command> statement that
      includes an <literal>ON CONFLICT DO UPDATE</literal> clause.
     </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"/> command.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] )</literal></term>
    <listitem>
     <para>
      This clause specifies optional storage parameters for a table or index;
      see <xref linkend="sql-createtable-storage-parameters"
      endterm="sql-createtable-storage-parameters-title"/> for more
      information.  The <literal>WITH</literal> clause for a
      table can also include <literal>OIDS=TRUE</literal> (or just <literal>OIDS</literal>)
      to specify that rows of the new table
      should have OIDs (object identifiers) assigned to them, or
      <literal>OIDS=FALSE</literal> to specify that the rows should not have OIDs.
      If <literal>OIDS</literal> is not specified, the default setting depends upon
      the <xref linkend="guc-default-with-oids"/> configuration parameter.
      (If the new table inherits from any tables that have OIDs, then
      <literal>OIDS=TRUE</literal> is forced even if the command says
      <literal>OIDS=FALSE</literal>.)
     </para>

     <para>
      If <literal>OIDS=FALSE</literal> is specified or implied, the new
      table does not store OIDs and no OID will be assigned for a row inserted
      into it. This is generally considered worthwhile, since it
      will reduce OID consumption and thereby postpone the wraparound
      of the 32-bit OID counter. Once the counter wraps around, OIDs
      can no longer be assumed to be unique, which makes them
      considerably less useful. In addition, excluding OIDs from a
      table reduces the space required to store the table on disk by
      4 bytes per row (on most machines), slightly improving performance.
     </para>

     <para>
      To remove OIDs from a table after it has been created, use <xref
      linkend="sql-altertable"/>.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>WITH OIDS</literal></term>
    <term><literal>WITHOUT OIDS</literal></term>
    <listitem>
     <para>
      These are obsolescent syntaxes equivalent to <literal>WITH (OIDS)</literal>
      and <literal>WITH (OIDS=FALSE)</literal>, respectively.  If you wish to give
      both an <literal>OIDS</literal> setting and storage parameters, you must use
      the <literal>WITH ( ... )</literal> syntax; see above.
     </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>

   <varlistentry>
    <term><literal>TABLESPACE <replaceable class="parameter">tablespace_name</replaceable></literal></term>
    <listitem>
     <para>
      The <replaceable class="parameter">tablespace_name</replaceable> is the name
      of the tablespace in which the new table is to be created.
      If not specified,
      <xref linkend="guc-default-tablespace"/> is consulted, or
      <xref linkend="guc-temp-tablespaces"/> if the table is temporary.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>USING INDEX TABLESPACE <replaceable class="parameter">tablespace_name</replaceable></literal></term>
    <listitem>
     <para>
      This clause allows selection of the tablespace in which the index
      associated with a <literal>UNIQUE</literal>, <literal>PRIMARY
      KEY</literal>, or <literal>EXCLUDE</literal> constraint will be created.
      If not specified,
      <xref linkend="guc-default-tablespace"/> is consulted, or
      <xref linkend="guc-temp-tablespaces"/> if the table is temporary.
     </para>
    </listitem>
   </varlistentry>

  </variablelist>

  <refsect2 id="sql-createtable-storage-parameters">
   <title id="sql-createtable-storage-parameters-title">Storage Parameters</title>

 <indexterm zone="sql-createtable-storage-parameters">
  <primary>storage parameters</primary>
 </indexterm>

   <para>
    The <literal>WITH</literal> clause can specify <firstterm>storage parameters</firstterm>
    for tables, and for indexes associated with a <literal>UNIQUE</literal>,
    <literal>PRIMARY KEY</literal>, or <literal>EXCLUDE</literal> constraint.
    Storage parameters for
    indexes are documented in <xref linkend="sql-createindex"/>.
    The storage parameters currently
    available for tables are listed below.  For many of these parameters, as
    shown, there is an additional parameter with the same name prefixed with
    <literal>toast.</literal>, which controls the behavior of the
    table's secondary <acronym>TOAST</acronym> table, if any
    (see <xref linkend="storage-toast"/> for more information about TOAST).
    If a table parameter value is set and the
    equivalent <literal>toast.</literal> parameter is not, the TOAST table
    will use the table's parameter value.
    Specifying these parameters for partitioned tables is not supported,
    but you may specify them for individual leaf partitions.
   </para>

   <variablelist>

   <varlistentry>
    <term><literal>fillfactor</literal> (<type>integer</type>)</term>
    <listitem>
     <para>
      The fillfactor for a table is a percentage between 10 and 100.
      100 (complete packing) is the default.  When a smaller fillfactor
      is specified, <command>INSERT</command> operations pack table pages only
      to the indicated percentage; the remaining space on each page is
      reserved for updating rows on that page.  This gives <command>UPDATE</command>
      a chance to place the updated copy of a row on the same page as the
      original, which is more efficient than placing it on a different page.
      For a table whose entries are never updated, complete packing is the
      best choice, but in heavily updated tables smaller fillfactors are
      appropriate.  This parameter cannot be set for TOAST tables.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>toast_tuple_target</literal> (<type>integer</type>)</term>
    <listitem>
     <para>
      The toast_tuple_target specifies the minimum tuple length required before
      we try to move long column values into TOAST tables, and is also the
      target length we try to reduce the length below once toasting begins.
      This only affects columns marked as either External or Extended
      and applies only to new tuples - there is no effect on existing rows.
      By default this parameter is set to allow at least 4 tuples per block,
      which with the default blocksize will be 2040 bytes. Valid values are
      between 128 bytes and the (blocksize - header), by default 8160 bytes.
      Changing this value may not be useful for very short or very long rows.
      Note that the default setting is often close to optimal, and
      it is possible that setting this parameter could have negative
      effects in some cases.
      This parameter cannot be set for TOAST tables.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>parallel_workers</literal> (<type>integer</type>)</term>
    <listitem>
     <para>
      This sets the number of workers that should be used to assist a parallel
      scan of this table.  If not set, the system will determine a value based
      on the relation size.  The actual number of workers chosen by the planner
      may be less, for example due to
      the setting of <xref linkend="guc-max-worker-processes"/>.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>autovacuum_enabled</literal>, <literal>toast.autovacuum_enabled</literal> (<type>boolean</type>)</term>
    <listitem>
     <para>
     Enables or disables the autovacuum daemon for a particular table.
     If true, the autovacuum daemon will perform automatic <command>VACUUM</command>
     and/or <command>ANALYZE</command> operations on this table following the rules
     discussed in <xref linkend="autovacuum"/>.
     If false, this table will not be autovacuumed, except to prevent
     transaction ID wraparound. See <xref linkend="vacuum-for-wraparound"/> for
     more about wraparound prevention.
     Note that the autovacuum daemon does not run at all (except to prevent
     transaction ID wraparound) if the <xref linkend="guc-autovacuum"/>
     parameter is false; setting individual tables' storage parameters does
     not override that.  Therefore there is seldom much point in explicitly
     setting this storage parameter to <literal>true</literal>, only
     to <literal>false</literal>.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>autovacuum_vacuum_threshold</literal>, <literal>toast.autovacuum_vacuum_threshold</literal> (<type>integer</type>)</term>
    <listitem>
     <para>
      Per-table value for <xref linkend="guc-autovacuum-vacuum-threshold"/>
      parameter.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>autovacuum_vacuum_scale_factor</literal>, <literal>toast.autovacuum_vacuum_scale_factor</literal> (<type>float4</type>)</term>
    <listitem>
     <para>
      Per-table value for <xref linkend="guc-autovacuum-vacuum-scale-factor"/>
      parameter.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>autovacuum_analyze_threshold</literal> (<type>integer</type>)</term>
    <listitem>
     <para>
      Per-table value for <xref linkend="guc-autovacuum-analyze-threshold"/>
      parameter.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>autovacuum_analyze_scale_factor</literal> (<type>float4</type>)</term>
    <listitem>
     <para>
      Per-table value for <xref linkend="guc-autovacuum-analyze-scale-factor"/>
      parameter.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>autovacuum_vacuum_cost_delay</literal>, <literal>toast.autovacuum_vacuum_cost_delay</literal> (<type>integer</type>)</term>
    <listitem>
     <para>
      Per-table value for <xref linkend="guc-autovacuum-vacuum-cost-delay"/>
      parameter.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>autovacuum_vacuum_cost_limit</literal>, <literal>toast.autovacuum_vacuum_cost_limit</literal> (<type>integer</type>)</term>
    <listitem>
     <para>
      Per-table value for <xref linkend="guc-autovacuum-vacuum-cost-limit"/>
      parameter.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>autovacuum_freeze_min_age</literal>, <literal>toast.autovacuum_freeze_min_age</literal> (<type>integer</type>)</term>
    <listitem>
     <para>
      Per-table value for <xref linkend="guc-vacuum-freeze-min-age"/>
      parameter.  Note that autovacuum will ignore
      per-table <literal>autovacuum_freeze_min_age</literal> parameters that are
      larger than half the
      system-wide <xref linkend="guc-autovacuum-freeze-max-age"/> setting.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>autovacuum_freeze_max_age</literal>, <literal>toast.autovacuum_freeze_max_age</literal> (<type>integer</type>)</term>
    <listitem>
     <para>
      Per-table value for <xref linkend="guc-autovacuum-freeze-max-age"/>
      parameter.  Note that autovacuum will ignore
      per-table <literal>autovacuum_freeze_max_age</literal> parameters that are
      larger than the system-wide setting (it can only be set smaller).
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>autovacuum_freeze_table_age</literal>, <literal>toast.autovacuum_freeze_table_age</literal> (<type>integer</type>)</term>
    <listitem>
     <para>
      Per-table value for <xref linkend="guc-vacuum-freeze-table-age"/>
      parameter.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>autovacuum_multixact_freeze_min_age</literal>, <literal>toast.autovacuum_multixact_freeze_min_age</literal> (<type>integer</type>)</term>
    <listitem>
     <para>
      Per-table value for <xref linkend="guc-vacuum-multixact-freeze-min-age"/>
      parameter.  Note that autovacuum will ignore
      per-table <literal>autovacuum_multixact_freeze_min_age</literal> parameters
      that are larger than half the
      system-wide <xref linkend="guc-autovacuum-multixact-freeze-max-age"/>
      setting.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>autovacuum_multixact_freeze_max_age</literal>, <literal>toast.autovacuum_multixact_freeze_max_age</literal> (<type>integer</type>)</term>
    <listitem>
     <para>
      Per-table value
      for <xref linkend="guc-autovacuum-multixact-freeze-max-age"/> parameter.
      Note that autovacuum will ignore
      per-table <literal>autovacuum_multixact_freeze_max_age</literal> parameters
      that are larger than the system-wide setting (it can only be set
      smaller).
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>autovacuum_multixact_freeze_table_age</literal>, <literal>toast.autovacuum_multixact_freeze_table_age</literal> (<type>integer</type>)</term>
    <listitem>
     <para>
      Per-table value
      for <xref linkend="guc-vacuum-multixact-freeze-table-age"/> parameter.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>log_autovacuum_min_duration</literal>, <literal>toast.log_autovacuum_min_duration</literal> (<type>integer</type>)</term>
    <listitem>
     <para>
      Per-table value for <xref linkend="guc-log-autovacuum-min-duration"/>
      parameter.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>user_catalog_table</literal> (<type>boolean</type>)</term>
    <listitem>
     <para>
      Declare the table as an additional catalog table for purposes of
      logical replication. See
      <xref linkend="logicaldecoding-capabilities"/> for details.
      This parameter cannot be set for TOAST tables.
     </para>
    </listitem>
   </varlistentry>

   </variablelist>

  </refsect2>
 </refsect1>

 <refsect1 id="sql-createtable-notes">
  <title>Notes</title>

    <para>
     Using OIDs in new applications is not recommended: where
     possible, using an identity column or other sequence
     generator as the table's primary key is preferred. However, if
     your application does make use of OIDs to identify specific
     rows of a table, it is recommended to create a unique constraint
     on the <structfield>oid</structfield> 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</structfield> and row OID for the
     purpose.
    </para>

    <tip>
     <para>
      The use of <literal>OIDS=FALSE</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>

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

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

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

 </refsect1>


 <refsect1 id="sql-createtable-examples">
  <title>Examples</title>

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

<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
);

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

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

<programlisting>
CREATE TABLE array_int (
    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 &gt; 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 &gt; 100 AND name &lt;&gt; '')
);
</programlisting>
  </para>

  <para>
   Define a primary key table constraint for the table
   <structname>films</structname>:

<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</structname>.  The following two examples are
   equivalent, the first using the table constraint syntax, the second
   the column constraint syntax:

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

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

  <para>
   Assign a literal constant default value for the column
   <literal>name</literal>, arrange for the default value of column
   <literal>did</literal> to be generated by selecting the next value
   of a sequence object, and make 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</literal> 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 same, specified as a table constraint:

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

  <para>
   Create the same table, specifying 70% fill factor for both the table
   and its unique index:

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

  <para>
   Create table <structname>circles</structname> with an exclusion
   constraint that prevents any two circles from overlapping:

<programlisting>
CREATE TABLE circles (
    c circle,
    EXCLUDE USING gist (c WITH &amp;&amp;)
);
</programlisting>
  </para>

  <para>
   Create table <structname>cinemas</structname> in tablespace <structname>diskvol1</structname>:

<programlisting>
CREATE TABLE cinemas (
        id serial,
        name text,
        location text
) TABLESPACE diskvol1;
</programlisting>
  </para>

  <para>
   Create a composite type and a typed table:
<programlisting>
CREATE TYPE employee_type AS (name text, salary numeric);

CREATE TABLE employees OF employee_type (
    PRIMARY KEY (name),
    salary WITH OPTIONS DEFAULT 1000
);
</programlisting></para>

  <para>
   Create a range partitioned table:
<programlisting>
CREATE TABLE measurement (
    logdate         date not null,
    peaktemp        int,
    unitsales       int
) PARTITION BY RANGE (logdate);
</programlisting></para>

  <para>
   Create a range partitioned table with multiple columns in the partition key:
<programlisting>
CREATE TABLE measurement_year_month (
    logdate         date not null,
    peaktemp        int,
    unitsales       int
) PARTITION BY RANGE (EXTRACT(YEAR FROM logdate), EXTRACT(MONTH FROM logdate));
</programlisting></para>

  <para>
   Create a list partitioned table:
<programlisting>
CREATE TABLE cities (
    city_id      bigserial not null,
    name         text not null,
    population   bigint
) PARTITION BY LIST (left(lower(name), 1));
</programlisting></para>

  <para>
   Create a hash partitioned table:
<programlisting>
CREATE TABLE orders (
    order_id     bigint not null,
    cust_id      bigint not null,
    status       text
) PARTITION BY HASH (order_id);
</programlisting></para>

  <para>
   Create partition of a range partitioned table:
<programlisting>
CREATE TABLE measurement_y2016m07
    PARTITION OF measurement (
    unitsales DEFAULT 0
) FOR VALUES FROM ('2016-07-01') TO ('2016-08-01');
</programlisting></para>

  <para>
   Create a few partitions of a range partitioned table with multiple
   columns in the partition key:
<programlisting>
CREATE TABLE measurement_ym_older
    PARTITION OF measurement_year_month
    FOR VALUES FROM (MINVALUE, MINVALUE) TO (2016, 11);

CREATE TABLE measurement_ym_y2016m11
    PARTITION OF measurement_year_month
    FOR VALUES FROM (2016, 11) TO (2016, 12);

CREATE TABLE measurement_ym_y2016m12
    PARTITION OF measurement_year_month
    FOR VALUES FROM (2016, 12) TO (2017, 01);

CREATE TABLE measurement_ym_y2017m01
    PARTITION OF measurement_year_month
    FOR VALUES FROM (2017, 01) TO (2017, 02);
</programlisting></para>

  <para>
   Create partition of a list partitioned table:
<programlisting>
CREATE TABLE cities_ab
    PARTITION OF cities (
    CONSTRAINT city_id_nonzero CHECK (city_id != 0)
) FOR VALUES IN ('a', 'b');
</programlisting></para>

  <para>
   Create partition of a list partitioned table that is itself further
   partitioned and then add a partition to it:
<programlisting>
CREATE TABLE cities_ab
    PARTITION OF cities (
    CONSTRAINT city_id_nonzero CHECK (city_id != 0)
) FOR VALUES IN ('a', 'b') PARTITION BY RANGE (population);

CREATE TABLE cities_ab_10000_to_100000
    PARTITION OF cities_ab FOR VALUES FROM (10000) TO (100000);
</programlisting></para>

  <para>
   Create partitions of a hash partitioned table:
<programlisting>
CREATE TABLE orders_p1 PARTITION OF orders
    FOR VALUES WITH (MODULUS 4, REMAINDER 0);
CREATE TABLE orders_p2 PARTITION OF orders
    FOR VALUES WITH (MODULUS 4, REMAINDER 1);
CREATE TABLE orders_p3 PARTITION OF orders
    FOR VALUES WITH (MODULUS 4, REMAINDER 2);
CREATE TABLE orders_p4 PARTITION OF orders
    FOR VALUES WITH (MODULUS 4, REMAINDER 3);
</programlisting></para>

  <para>
   Create a default partition:
<programlisting>
CREATE TABLE cities_partdef
    PARTITION OF cities DEFAULT;
</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 the
   <acronym>SQL</acronym> standard, 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 SQL standard also distinguishes between global and local temporary
    tables, where a local temporary table has a separate set of contents for
    each SQL module within each session, though its definition is still shared
    across sessions.  Since <productname>PostgreSQL</productname> does not
    support SQL modules, this distinction is not relevant in
    <productname>PostgreSQL</productname>.
   </para>

   <para>
    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 currently have no effect.
    Use of these keywords is discouraged, since future versions of
    <productname>PostgreSQL</productname> might adopt a more
    standard-compliant interpretation of their meaning.
   </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</literal> clause is omitted, SQL specifies that the
    default behavior is <literal>ON COMMIT DELETE ROWS</literal>.  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>Non-deferred Uniqueness Constraints</title>

   <para>
    When a <literal>UNIQUE</literal> or <literal>PRIMARY KEY</literal> constraint is
    not deferrable, <productname>PostgreSQL</productname> checks for
    uniqueness immediately whenever a row is inserted or modified.
    The SQL standard says that uniqueness should be enforced only at
    the end of the statement; this makes a difference when, for example,
    a single command updates multiple key values.  To obtain
    standard-compliant behavior, declare the constraint as
    <literal>DEFERRABLE</literal> but not deferred (i.e., <literal>INITIALLY
    IMMEDIATE</literal>).  Be aware that this can be significantly slower than
    immediate uniqueness checking.
   </para>
  </refsect2>

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

   <para>
    The SQL standard says that <literal>CHECK</literal> column constraints
    can only refer to the column they apply to; only <literal>CHECK</literal>
    table constraints can 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>EXCLUDE</literal> Constraint</title>

   <para>
    The <literal>EXCLUDE</literal> constraint type is a
    <productname>PostgreSQL</productname> extension.
   </para>
  </refsect2>

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

   <para>
    The <literal>NULL</literal> <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.
    SQL:1999 and later define single inheritance using a
    different syntax and different semantics.  SQL:1999-style
    inheritance is not yet supported by
    <productname>PostgreSQL</productname>.
   </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();</literal>).  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</command>, so it seems cleaner to ignore this spec restriction.
   </para>
  </refsect2>

  <refsect2>
   <title>Multiple Identity Columns</title>

   <para>
    <productname>PostgreSQL</productname> allows a table to have more than one
    identity column.  The standard specifies that a table can have at most one
    identity column.  This is relaxed mainly to give more flexibility for
    doing schema changes or migrations.  Note that
    the <command>INSERT</command> command supports only one override clause
    that applies to the entire statement, so having multiple identity columns
    with different behaviors is not well supported.
   </para>
  </refsect2>

  <refsect2>
   <title><literal>LIKE</literal> Clause</title>

   <para>
    While a <literal>LIKE</literal> clause exists in the SQL standard, many of the
    options that <productname>PostgreSQL</productname> accepts for it are not
    in the standard, and some of the standard's options are not implemented
    by <productname>PostgreSQL</productname>.
   </para>
  </refsect2>

  <refsect2>
   <title><literal>WITH</literal> Clause</title>

   <para>
    The <literal>WITH</literal> clause is a <productname>PostgreSQL</productname>
    extension; neither storage parameters nor OIDs are in the standard.
   </para>
  </refsect2>

  <refsect2>
   <title>Tablespaces</title>

   <para>
    The <productname>PostgreSQL</productname> concept of tablespaces is not
    part of the standard.  Hence, the clauses <literal>TABLESPACE</literal>
    and <literal>USING INDEX TABLESPACE</literal> are extensions.
   </para>
  </refsect2>

  <refsect2>
   <title>Typed Tables</title>

   <para>
    Typed tables implement a subset of the SQL standard.  According to
    the standard, a typed table has columns corresponding to the
    underlying composite type as well as one other column that is
    the <quote>self-referencing column</quote>.  PostgreSQL does not
    support these self-referencing columns explicitly, but the same
    effect can be had using the OID feature.
   </para>
  </refsect2>

  <refsect2>
   <title><literal>PARTITION BY</literal> Clause</title>

   <para>
    The <literal>PARTITION BY</literal> clause is a
    <productname>PostgreSQL</productname> extension.
   </para>
  </refsect2>

  <refsect2>
   <title><literal>PARTITION OF</literal> Clause</title>

   <para>
    The <literal>PARTITION OF</literal> clause is a
    <productname>PostgreSQL</productname> extension.
   </para>
  </refsect2>

 </refsect1>


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

  <simplelist type="inline">
   <member><xref linkend="sql-altertable"/></member>
   <member><xref linkend="sql-droptable"/></member>
   <member><xref linkend="sql-createtableas"/></member>
   <member><xref linkend="sql-createtablespace"/></member>
   <member><xref linkend="sql-createtype"/></member>
  </simplelist>
 </refsect1>
</refentry>