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
2017
2018
2019
2020
2021
2022
2023
2024
2025
2026
2027
2028
2029
2030
2031
2032
2033
2034
2035
2036
2037
2038
2039
2040
2041
2042
2043
2044
2045
2046
2047
2048
2049
2050
2051
2052
2053
2054
2055
2056
2057
2058
2059
2060
2061
2062
2063
2064
2065
2066
2067
2068
2069
2070
2071
2072
2073
2074
2075
2076
2077
2078
2079
2080
2081
2082
2083
2084
2085
2086
2087
2088
2089
2090
2091
2092
2093
2094
2095
2096
2097
2098
2099
2100
2101
2102
2103
2104
2105
2106
2107
2108
2109
2110
2111
2112
2113
2114
2115
2116
2117
2118
2119
2120
2121
2122
2123
2124
2125
2126
2127
2128
2129
2130
2131
2132
2133
2134
2135
2136
2137
2138
2139
2140
2141
2142
2143
2144
2145
2146
2147
2148
2149
2150
2151
2152
2153
2154
2155
2156
2157
2158
2159
2160
2161
2162
2163
2164
2165
2166
2167
2168
2169
2170
2171
2172
2173
2174
2175
2176
2177
2178
2179
2180
2181
2182
2183
2184
2185
2186
2187
2188
2189
2190
2191
2192
2193
2194
2195
2196
2197
2198
2199
2200
2201
2202
2203
2204
2205
2206
2207
2208
2209
2210
2211
2212
2213
2214
2215
2216
2217
2218
2219
2220
2221
2222
2223
2224
2225
2226
2227
2228
2229
2230
2231
2232
2233
2234
2235
2236
2237
2238
2239
2240
2241
2242
2243
2244
2245
2246
2247
2248
2249
2250
2251
2252
2253
2254
2255
2256
2257
2258
2259
2260
2261
2262
2263
2264
2265
2266
2267
2268
2269
2270
2271
2272
2273
2274
2275
2276
2277
2278
2279
2280
2281
2282
2283
2284
2285
2286
2287
2288
2289
2290
2291
2292
2293
2294
2295
2296
2297
2298
2299
2300
2301
2302
2303
2304
2305
2306
2307
2308
2309
2310
2311
2312
2313
2314
2315
2316
2317
2318
2319
2320
2321
2322
2323
2324
2325
2326
2327
2328
2329
2330
2331
2332
2333
2334
2335
2336
2337
2338
2339
2340
2341
2342
2343
2344
2345
2346
2347
2348
2349
2350
2351
2352
2353
2354
2355
2356
2357
2358
2359
2360
2361
2362
2363
2364
2365
2366
2367
2368
2369
2370
2371
2372
2373
2374
2375
2376
2377
2378
2379
2380
2381
2382
2383
2384
2385
2386
2387
2388
2389
2390
2391
2392
2393
2394
2395
2396
2397
2398
2399
2400
2401
2402
2403
2404
2405
2406
2407
2408
2409
2410
2411
2412
2413
2414
2415
2416
2417
2418
2419
2420
2421
2422
2423
2424
2425
2426
2427
2428
2429
2430
2431
2432
2433
2434
2435
2436
2437
2438
2439
2440
2441
2442
2443
2444
2445
2446
2447
2448
2449
2450
2451
2452
2453
2454
2455
2456
2457
2458
2459
2460
2461
2462
2463
2464
2465
2466
2467
2468
2469
2470
2471
2472
2473
2474
2475
2476
2477
2478
2479
2480
2481
2482
2483
2484
2485
2486
2487
2488
2489
2490
2491
2492
2493
2494
2495
2496
2497
2498
2499
2500
2501
2502
2503
2504
2505
2506
2507
2508
2509
2510
2511
2512
2513
2514
2515
2516
2517
2518
2519
2520
2521
2522
2523
2524
2525
2526
2527
2528
2529
2530
2531
2532
2533
2534
2535
2536
2537
2538
2539
2540
2541
2542
2543
2544
2545
2546
2547
2548
2549
2550
2551
2552
2553
2554
2555
2556
2557
2558
2559
2560
2561
2562
2563
2564
2565
2566
2567
2568
2569
2570
2571
2572
2573
2574
2575
2576
2577
2578
2579
2580
2581
2582
2583
2584
2585
2586
2587
2588
2589
2590
2591
2592
2593
2594
2595
2596
2597
2598
2599
2600
2601
2602
2603
2604
2605
2606
2607
2608
2609
2610
2611
2612
2613
2614
2615
2616
2617
2618
2619
2620
2621
2622
2623
2624
2625
2626
2627
2628
2629
2630
2631
2632
2633
2634
2635
2636
2637
2638
2639
2640
2641
2642
2643
2644
2645
2646
2647
2648
2649
2650
2651
2652
2653
2654
2655
2656
2657
2658
2659
2660
2661
2662
2663
2664
2665
2666
2667
2668
2669
2670
2671
2672
2673
2674
2675
2676
2677
2678
2679
2680
2681
2682
2683
2684
2685
2686
2687
2688
2689
2690
2691
2692
2693
2694
2695
2696
2697
2698
2699
2700
2701
2702
2703
2704
2705
2706
2707
2708
2709
2710
2711
2712
2713
2714
2715
2716
2717
2718
2719
2720
2721
2722
2723
2724
2725
2726
2727
2728
2729
2730
2731
2732
2733
2734
2735
2736
2737
2738
2739
2740
2741
2742
2743
2744
2745
2746
2747
2748
2749
2750
2751
2752
2753
2754
2755
2756
2757
2758
2759
2760
2761
2762
2763
2764
2765
2766
2767
2768
2769
2770
2771
2772
2773
2774
2775
2776
2777
2778
2779
2780
2781
2782
2783
2784
2785
2786
2787
2788
2789
2790
2791
2792
2793
2794
2795
2796
2797
2798
2799
2800
2801
2802
2803
2804
2805
2806
2807
2808
2809
2810
2811
2812
2813
2814
2815
2816
2817
2818
2819
2820
2821
2822
2823
2824
2825
2826
2827
2828
2829
2830
2831
2832
2833
2834
2835
2836
2837
2838
2839
2840
2841
2842
2843
2844
2845
2846
2847
2848
2849
2850
2851
2852
2853
2854
2855
2856
2857
2858
2859
2860
2861
2862
2863
2864
2865
2866
2867
2868
2869
2870
2871
2872
2873
2874
2875
2876
2877
2878
2879
2880
2881
2882
2883
2884
2885
2886
2887
2888
2889
2890
2891
2892
2893
2894
2895
2896
2897
2898
2899
2900
2901
2902
2903
2904
2905
2906
2907
2908
2909
2910
2911
2912
2913
2914
2915
2916
2917
2918
2919
2920
2921
2922
2923
2924
2925
2926
2927
2928
2929
2930
2931
2932
2933
2934
2935
2936
2937
2938
2939
2940
2941
2942
2943
2944
2945
2946
2947
2948
2949
2950
2951
2952
2953
2954
2955
2956
2957
2958
2959
2960
2961
2962
2963
2964
2965
2966
2967
2968
2969
2970
2971
2972
2973
2974
2975
2976
2977
2978
2979
2980
2981
2982
2983
2984
2985
2986
2987
2988
2989
2990
2991
2992
2993
2994
2995
2996
2997
2998
2999
3000
3001
3002
3003
3004
3005
3006
3007
3008
3009
3010
3011
3012
3013
3014
3015
3016
3017
3018
3019
3020
3021
3022
3023
3024
3025
3026
3027
3028
3029
3030
3031
3032
3033
3034
3035
3036
3037
3038
3039
3040
3041
3042
3043
3044
3045
3046
3047
3048
3049
3050
3051
3052
3053
3054
3055
3056
3057
3058
3059
3060
3061
3062
3063
3064
3065
3066
3067
3068
3069
3070
3071
3072
3073
3074
3075
3076
3077
3078
3079
3080
3081
3082
3083
3084
3085
3086
3087
3088
3089
3090
3091
3092
3093
3094
3095
3096
3097
3098
3099
3100
3101
3102
3103
3104
3105
3106
3107
3108
3109
3110
3111
3112
3113
3114
3115
3116
3117
3118
3119
3120
3121
3122
3123
3124
3125
3126
3127
3128
3129
3130
3131
3132
3133
3134
3135
3136
3137
3138
3139
3140
3141
3142
3143
3144
3145
3146
3147
3148
3149
3150
3151
3152
3153
3154
3155
3156
3157
3158
3159
3160
3161
3162
3163
3164
3165
3166
3167
3168
3169
3170
3171
3172
3173
3174
3175
3176
3177
3178
3179
3180
3181
3182
3183
3184
3185
3186
3187
3188
3189
3190
3191
3192
3193
3194
3195
3196
3197
3198
3199
3200
3201
3202
3203
3204
3205
3206
3207
3208
3209
3210
3211
3212
3213
3214
3215
3216
3217
3218
3219
3220
3221
3222
3223
3224
3225
3226
3227
3228
3229
3230
3231
3232
3233
3234
3235
3236
3237
3238
3239
3240
3241
3242
3243
3244
3245
3246
3247
3248
3249
3250
3251
3252
3253
3254
3255
3256
3257
3258
3259
3260
3261
3262
3263
3264
3265
3266
3267
3268
3269
3270
3271
3272
3273
3274
3275
3276
3277
3278
3279
3280
3281
3282
3283
3284
3285
3286
3287
3288
3289
3290
3291
3292
3293
3294
3295
3296
3297
3298
3299
3300
3301
3302
3303
3304
3305
3306
3307
3308
3309
3310
3311
3312
3313
3314
3315
3316
3317
3318
3319
3320
3321
3322
3323
3324
3325
3326
3327
3328
3329
3330
3331
3332
3333
3334
3335
3336
3337
3338
3339
3340
3341
3342
3343
3344
3345
3346
3347
3348
3349
3350
3351
3352
3353
3354
3355
3356
3357
3358
3359
3360
3361
3362
3363
3364
3365
3366
3367
3368
3369
3370
3371
3372
3373
3374
3375
3376
3377
3378
3379
3380
3381
3382
3383
3384
3385
3386
3387
3388
3389
3390
3391
3392
3393
3394
3395
3396
3397
3398
3399
3400
3401
3402
3403
3404
3405
3406
3407
3408
3409
3410
3411
3412
3413
3414
3415
3416
3417
3418
3419
3420
3421
3422
3423
3424
3425
3426
3427
3428
3429
3430
3431
3432
3433
3434
3435
3436
3437
3438
3439
3440
3441
3442
3443
3444
3445
3446
3447
3448
3449
3450
3451
3452
3453
3454
3455
3456
3457
3458
3459
3460
3461
3462
3463
3464
3465
3466
3467
3468
3469
3470
3471
3472
3473
3474
3475
3476
3477
3478
3479
3480
3481
3482
3483
3484
3485
3486
3487
3488
3489
3490
3491
3492
3493
3494
3495
3496
3497
3498
3499
3500
3501
3502
3503
3504
3505
3506
3507
3508
3509
3510
3511
3512
3513
3514
3515
3516
3517
3518
3519
3520
3521
3522
3523
3524
3525
3526
3527
3528
3529
3530
3531
3532
3533
3534
3535
3536
3537
3538
3539
3540
3541
3542
3543
3544
3545
3546
3547
3548
3549
3550
3551
3552
3553
3554
3555
3556
3557
3558
3559
3560
3561
3562
3563
3564
3565
3566
3567
3568
3569
3570
3571
3572
3573
3574
3575
3576
3577
3578
3579
3580
3581
3582
3583
3584
3585
3586
3587
3588
3589
3590
3591
3592
3593
3594
3595
3596
3597
3598
3599
3600
3601
3602
3603
3604
3605
3606
3607
3608
3609
3610
3611
3612
3613
3614
3615
3616
3617
3618
3619
3620
3621
3622
3623
3624
3625
3626
3627
3628
3629
3630
3631
3632
3633
3634
3635
3636
3637
3638
3639
3640
3641
3642
3643
3644
3645
3646
3647
3648
3649
3650
3651
3652
3653
3654
3655
3656
3657
3658
3659
3660
3661
3662
3663
3664
3665
3666
3667
3668
3669
3670
3671
3672
3673
3674
3675
3676
3677
3678
3679
3680
3681
3682
3683
3684
3685
3686
3687
3688
3689
3690
3691
3692
3693
3694
3695
3696
3697
3698
3699
3700
3701
3702
3703
3704
3705
3706
3707
3708
3709
3710
3711
3712
3713
3714
3715
3716
3717
3718
3719
3720
3721
3722
3723
3724
3725
3726
3727
3728
3729
3730
3731
3732
3733
3734
3735
3736
3737
3738
3739
3740
3741
3742
3743
3744
3745
3746
3747
3748
3749
3750
3751
3752
3753
3754
3755
3756
3757
3758
3759
3760
3761
3762
3763
3764
3765
3766
3767
3768
3769
3770
3771
3772
3773
3774
3775
3776
3777
3778
3779
3780
3781
3782
3783
3784
3785
3786
3787
3788
3789
3790
3791
3792
3793
3794
3795
3796
3797
3798
3799
3800
3801
3802
3803
3804
3805
3806
3807
3808
3809
3810
3811
3812
3813
3814
3815
3816
3817
3818
3819
3820
3821
3822
3823
3824
3825
3826
3827
3828
3829
3830
3831
3832
3833
3834
3835
3836
3837
3838
3839
3840
3841
3842
3843
3844
3845
3846
3847
3848
3849
3850
3851
3852
3853
3854
3855
3856
3857
3858
3859
3860
3861
3862
3863
3864
3865
3866
3867
3868
3869
3870
3871
3872
3873
3874
3875
3876
3877
3878
3879
3880
3881
3882
3883
3884
3885
3886
3887
3888
3889
3890
3891
3892
3893
3894
3895
3896
3897
3898
3899
3900
3901
3902
3903
3904
3905
3906
3907
3908
3909
3910
3911
3912
3913
3914
3915
3916
3917
3918
3919
3920
3921
3922
3923
3924
3925
3926
3927
3928
3929
3930
3931
3932
3933
3934
3935
3936
3937
3938
3939
3940
3941
3942
3943
3944
3945
3946
3947
3948
3949
3950
3951
3952
3953
3954
3955
3956
3957
3958
3959
3960
3961
3962
3963
3964
3965
3966
3967
3968
3969
3970
3971
3972
3973
3974
3975
3976
3977
3978
3979
3980
3981
3982
3983
3984
3985
3986
3987
3988
3989
3990
3991
3992
3993
3994
3995
3996
3997
3998
3999
4000
4001
4002
4003
4004
4005
4006
4007
4008
4009
4010
4011
4012
4013
4014
4015
4016
4017
4018
4019
4020
4021
4022
4023
4024
4025
4026
4027
4028
4029
4030
4031
4032
4033
4034
4035
4036
4037
4038
4039
4040
4041
4042
4043
4044
4045
4046
4047
4048
4049
4050
4051
4052
4053
4054
4055
4056
4057
4058
4059
4060
4061
4062
4063
4064
4065
4066
4067
4068
4069
4070
4071
4072
4073
4074
4075
4076
4077
4078
4079
4080
4081
4082
4083
4084
4085
4086
4087
4088
4089
4090
4091
4092
4093
4094
4095
4096
4097
4098
4099
4100
4101
4102
4103
4104
4105
4106
4107
4108
4109
4110
4111
4112
4113
4114
4115
4116
4117
4118
4119
4120
4121
4122
4123
4124
4125
4126
4127
4128
4129
4130
4131
4132
4133
4134
4135
4136
4137
4138
4139
4140
4141
4142
4143
4144
4145
4146
4147
4148
4149
4150
4151
4152
4153
4154
4155
4156
4157
4158
4159
4160
4161
4162
4163
4164
4165
4166
4167
4168
4169
4170
4171
4172
4173
4174
4175
4176
4177
4178
4179
4180
4181
4182
4183
4184
4185
4186
4187
4188
4189
4190
4191
4192
4193
4194
4195
4196
4197
4198
4199
4200
4201
4202
4203
4204
4205
4206
4207
4208
4209
4210
4211
4212
4213
4214
4215
4216
4217
4218
4219
4220
4221
4222
4223
4224
4225
4226
4227
4228
4229
4230
4231
4232
4233
4234
4235
4236
4237
4238
4239
4240
4241
4242
4243
4244
4245
4246
4247
4248
4249
4250
4251
4252
4253
4254
4255
4256
4257
4258
4259
4260
4261
4262
4263
4264
4265
4266
4267
4268
4269
4270
4271
4272
4273
4274
4275
4276
4277
4278
4279
4280
4281
4282
4283
4284
4285
4286
4287
4288
4289
4290
4291
4292
4293
4294
4295
4296
4297
4298
4299
4300
4301
4302
4303
4304
4305
4306
4307
4308
4309
4310
4311
4312
4313
4314
4315
4316
4317
4318
4319
4320
4321
4322
4323
4324
4325
4326
4327
4328
4329
4330
4331
4332
4333
4334
4335
4336
4337
4338
4339
4340
4341
4342
4343
4344
4345
4346
4347
4348
4349
4350
4351
4352
4353
4354
4355
4356
4357
4358
4359
4360
4361
4362
4363
4364
4365
4366
4367
4368
4369
4370
4371
4372
4373
4374
4375
4376
4377
4378
4379
4380
4381
4382
4383
4384
4385
4386
4387
4388
4389
4390
4391
4392
4393
4394
4395
4396
4397
4398
4399
4400
4401
4402
4403
4404
4405
4406
4407
4408
4409
4410
4411
4412
4413
4414
4415
4416
4417
4418
4419
4420
4421
4422
4423
4424
4425
4426
4427
4428
4429
4430
4431
4432
4433
4434
4435
4436
4437
4438
4439
4440
4441
4442
4443
4444
4445
4446
4447
4448
4449
4450
4451
4452
4453
4454
4455
4456
4457
4458
4459
4460
4461
4462
4463
4464
4465
4466
4467
4468
4469
4470
4471
4472
4473
4474
4475
4476
4477
4478
4479
4480
4481
4482
4483
4484
4485
4486
4487
4488
4489
4490
4491
4492
4493
4494
4495
4496
4497
4498
4499
4500
4501
4502
4503
4504
4505
4506
4507
4508
4509
4510
4511
4512
4513
4514
4515
4516
4517
4518
4519
4520
4521
4522
4523
4524
4525
4526
4527
4528
4529
4530
4531
4532
4533
4534
4535
4536
4537
4538
4539
4540
4541
4542
4543
4544
4545
4546
4547
4548
4549
4550
4551
4552
4553
4554
4555
4556
4557
4558
4559
4560
4561
4562
4563
4564
4565
4566
4567
4568
4569
4570
4571
4572
4573
4574
4575
4576
4577
4578
4579
4580
4581
4582
4583
4584
4585
4586
4587
4588
4589
4590
4591
4592
4593
4594
4595
4596
4597
4598
4599
4600
4601
4602
4603
4604
4605
4606
4607
4608
4609
4610
4611
4612
4613
4614
4615
4616
4617
4618
4619
4620
4621
4622
4623
4624
4625
4626
4627
4628
4629
4630
4631
4632
4633
4634
4635
4636
4637
4638
4639
4640
4641
4642
4643
4644
4645
4646
4647
4648
4649
4650
4651
4652
4653
4654
4655
4656
4657
4658
4659
4660
4661
4662
4663
4664
4665
4666
4667
4668
4669
4670
4671
4672
4673
4674
4675
4676
4677
4678
4679
4680
4681
4682
4683
4684
4685
4686
4687
4688
4689
4690
4691
4692
4693
4694
4695
4696
4697
4698
4699
4700
4701
4702
4703
4704
4705
4706
4707
4708
4709
4710
4711
4712
4713
4714
4715
4716
4717
4718
4719
4720
4721
4722
4723
4724
4725
4726
4727
4728
4729
4730
4731
4732
4733
4734
4735
4736
4737
4738
4739
4740
4741
4742
4743
4744
4745
4746
4747
4748
4749
4750
4751
4752
4753
4754
4755
4756
4757
4758
4759
4760
4761
4762
4763
4764
4765
4766
4767
4768
4769
4770
4771
4772
4773
4774
4775
4776
4777
4778
4779
4780
4781
4782
4783
4784
4785
4786
4787
4788
4789
4790
4791
4792
4793
4794
4795
4796
4797
4798
4799
4800
4801
4802
4803
4804
4805
4806
4807
4808
4809
4810
4811
4812
4813
4814
4815
4816
4817
4818
4819
4820
4821
4822
4823
4824
4825
4826
4827
4828
4829
4830
4831
4832
4833
4834
4835
4836
4837
4838
4839
4840
4841
4842
4843
4844
4845
4846
4847
4848
4849
4850
4851
4852
4853
4854
4855
4856
4857
4858
4859
4860
4861
4862
4863
4864
4865
4866
4867
4868
4869
4870
4871
4872
4873
4874
4875
4876
4877
4878
4879
4880
4881
4882
4883
4884
4885
4886
4887
4888
4889
4890
4891
4892
4893
4894
4895
4896
4897
4898
4899
4900
4901
4902
4903
4904
4905
4906
4907
4908
4909
4910
4911
4912
4913
4914
4915
4916
4917
4918
4919
4920
4921
4922
4923
4924
4925
4926
4927
4928
4929
4930
4931
4932
4933
4934
4935
4936
4937
4938
4939
4940
4941
4942
4943
4944
4945
4946
4947
4948
4949
4950
4951
4952
4953
4954
4955
4956
4957
4958
4959
4960
4961
4962
4963
4964
4965
4966
4967
4968
4969
4970
4971
4972
4973
4974
4975
4976
4977
4978
4979
4980
4981
4982
4983
4984
4985
4986
4987
4988
4989
4990
4991
4992
4993
4994
4995
4996
4997
4998
4999
5000
5001
5002
5003
5004
5005
5006
5007
5008
5009
5010
5011
5012
5013
5014
5015
5016
5017
5018
5019
5020
5021
5022
5023
5024
5025
5026
5027
5028
5029
5030
5031
5032
5033
5034
5035
5036
5037
5038
5039
5040
5041
5042
5043
5044
5045
5046
5047
5048
5049
5050
5051
5052
5053
5054
5055
5056
5057
5058
5059
5060
5061
5062
5063
5064
5065
5066
5067
5068
5069
5070
5071
5072
5073
5074
5075
5076
5077
5078
5079
5080
5081
5082
5083
5084
5085
5086
5087
5088
5089
5090
5091
5092
5093
5094
5095
5096
5097
5098
5099
5100
5101
5102
5103
5104
|
<!-- doc/src/sgml/ddl.sgml -->
<chapter id="ddl">
<title>Data Definition</title>
<para>
This chapter covers how one creates the database structures that
will hold one's data. In a relational database, the raw data is
stored in tables, so the majority of this chapter is devoted to
explaining how tables are created and modified and what features are
available to control what data is stored in the tables.
Subsequently, we discuss how tables can be organized into
schemas, and how privileges can be assigned to tables. Finally,
we will briefly look at other features that affect the data storage,
such as inheritance, table partitioning, views, functions, and
triggers.
</para>
<sect1 id="ddl-basics">
<title>Table Basics</title>
<indexterm zone="ddl-basics">
<primary>table</primary>
</indexterm>
<indexterm>
<primary>row</primary>
</indexterm>
<indexterm>
<primary>column</primary>
</indexterm>
<para>
A table in a relational database is much like a table on paper: It
consists of rows and columns. The number and order of the columns
is fixed, and each column has a name. The number of rows is
variable — it reflects how much data is stored at a given moment.
SQL does not make any guarantees about the order of the rows in a
table. When a table is read, the rows will appear in an unspecified order,
unless sorting is explicitly requested. This is covered in <xref
linkend="queries"/>. Furthermore, SQL does not assign unique
identifiers to rows, so it is possible to have several completely
identical rows in a table. This is a consequence of the
mathematical model that underlies SQL but is usually not desirable.
Later in this chapter we will see how to deal with this issue.
</para>
<para>
Each column has a data type. The data type constrains the set of
possible values that can be assigned to a column and assigns
semantics to the data stored in the column so that it can be used
for computations. For instance, a column declared to be of a
numerical type will not accept arbitrary text strings, and the data
stored in such a column can be used for mathematical computations.
By contrast, a column declared to be of a character string type
will accept almost any kind of data but it does not lend itself to
mathematical calculations, although other operations such as string
concatenation are available.
</para>
<para>
<productname>PostgreSQL</productname> includes a sizable set of
built-in data types that fit many applications. Users can also
define their own data types. Most built-in data types have obvious
names and semantics, so we defer a detailed explanation to <xref
linkend="datatype"/>. Some of the frequently used data types are
<type>integer</type> for whole numbers, <type>numeric</type> for
possibly fractional numbers, <type>text</type> for character
strings, <type>date</type> for dates, <type>time</type> for
time-of-day values, and <type>timestamp</type> for values
containing both date and time.
</para>
<indexterm>
<primary>table</primary>
<secondary>creating</secondary>
</indexterm>
<para>
To create a table, you use the aptly named <xref
linkend="sql-createtable"/> command.
In this command you specify at least a name for the new table, the
names of the columns and the data type of each column. For
example:
<programlisting>
CREATE TABLE my_first_table (
first_column text,
second_column integer
);
</programlisting>
This creates a table named <literal>my_first_table</literal> with
two columns. The first column is named
<literal>first_column</literal> and has a data type of
<type>text</type>; the second column has the name
<literal>second_column</literal> and the type <type>integer</type>.
The table and column names follow the identifier syntax explained
in <xref linkend="sql-syntax-identifiers"/>. The type names are
usually also identifiers, but there are some exceptions. Note that the
column list is comma-separated and surrounded by parentheses.
</para>
<para>
Of course, the previous example was heavily contrived. Normally,
you would give names to your tables and columns that convey what
kind of data they store. So let's look at a more realistic
example:
<programlisting>
CREATE TABLE products (
product_no integer,
name text,
price numeric
);
</programlisting>
(The <type>numeric</type> type can store fractional components, as
would be typical of monetary amounts.)
</para>
<tip>
<para>
When you create many interrelated tables it is wise to choose a
consistent naming pattern for the tables and columns. For
instance, there is a choice of using singular or plural nouns for
table names, both of which are favored by some theorist or other.
</para>
</tip>
<para>
There is a limit on how many columns a table can contain.
Depending on the column types, it is between 250 and 1600.
However, defining a table with anywhere near this many columns is
highly unusual and often a questionable design.
</para>
<indexterm>
<primary>table</primary>
<secondary>removing</secondary>
</indexterm>
<para>
If you no longer need a table, you can remove it using the <xref
linkend="sql-droptable"/> command.
For example:
<programlisting>
DROP TABLE my_first_table;
DROP TABLE products;
</programlisting>
Attempting to drop a table that does not exist is an error.
Nevertheless, it is common in SQL script files to unconditionally
try to drop each table before creating it, ignoring any error
messages, so that the script works whether or not the table exists.
(If you like, you can use the <literal>DROP TABLE IF EXISTS</literal> variant
to avoid the error messages, but this is not standard SQL.)
</para>
<para>
If you need to modify a table that already exists, see <xref
linkend="ddl-alter"/> later in this chapter.
</para>
<para>
With the tools discussed so far you can create fully functional
tables. The remainder of this chapter is concerned with adding
features to the table definition to ensure data integrity,
security, or convenience. If you are eager to fill your tables with
data now you can skip ahead to <xref linkend="dml"/> and read the
rest of this chapter later.
</para>
</sect1>
<sect1 id="ddl-default">
<title>Default Values</title>
<indexterm zone="ddl-default">
<primary>default value</primary>
</indexterm>
<para>
A column can be assigned a default value. When a new row is
created and no values are specified for some of the columns, those
columns will be filled with their respective default values. A
data manipulation command can also request explicitly that a column
be set to its default value, without having to know what that value is.
(Details about data manipulation commands are in <xref linkend="dml"/>.)
</para>
<para>
<indexterm><primary>null value</primary><secondary>default value</secondary></indexterm>
If no default value is declared explicitly, the default value is the
null value. This usually makes sense because a null value can
be considered to represent unknown data.
</para>
<para>
In a table definition, default values are listed after the column
data type. For example:
<programlisting>
CREATE TABLE products (
product_no integer,
name text,
price numeric <emphasis>DEFAULT 9.99</emphasis>
);
</programlisting>
</para>
<para>
The default value can be an expression, which will be
evaluated whenever the default value is inserted
(<emphasis>not</emphasis> when the table is created). A common example
is for a <type>timestamp</type> column to have a default of <literal>CURRENT_TIMESTAMP</literal>,
so that it gets set to the time of row insertion. Another common
example is generating a <quote>serial number</quote> for each row.
In <productname>PostgreSQL</productname> this is typically done by
something like:
<programlisting>
CREATE TABLE products (
product_no integer <emphasis>DEFAULT nextval('products_product_no_seq')</emphasis>,
...
);
</programlisting>
where the <literal>nextval()</literal> function supplies successive values
from a <firstterm>sequence object</firstterm> (see <xref
linkend="functions-sequence"/>). This arrangement is sufficiently common
that there's a special shorthand for it:
<programlisting>
CREATE TABLE products (
product_no <emphasis>SERIAL</emphasis>,
...
);
</programlisting>
The <literal>SERIAL</literal> shorthand is discussed further in <xref
linkend="datatype-serial"/>.
</para>
</sect1>
<sect1 id="ddl-generated-columns">
<title>Generated Columns</title>
<indexterm zone="ddl-generated-columns">
<primary>generated column</primary>
</indexterm>
<para>
A generated column is a special column that is always computed from other
columns. Thus, it is for columns what a view is for tables. There are two
kinds of generated columns: stored and virtual. A stored generated column
is computed when it is written (inserted or updated) and occupies storage
as if it were a normal column. A virtual generated column occupies no
storage and is computed when it is read. Thus, a virtual generated column
is similar to a view and a stored generated column is similar to a
materialized view (except that it is always updated automatically).
PostgreSQL currently implements only stored generated columns.
</para>
<para>
To create a generated column, use the <literal>GENERATED ALWAYS
AS</literal> clause in <command>CREATE TABLE</command>, for example:
<programlisting>
CREATE TABLE people (
...,
height_cm numeric,
height_in numeric <emphasis>GENERATED ALWAYS AS (height_cm / 2.54) STORED</emphasis>
);
</programlisting>
The keyword <literal>STORED</literal> must be specified to choose the
stored kind of generated column. See <xref linkend="sql-createtable"/> for
more details.
</para>
<para>
A generated column cannot be written to directly. In
<command>INSERT</command> or <command>UPDATE</command> commands, a value
cannot be specified for a generated column, but the keyword
<literal>DEFAULT</literal> may be specified.
</para>
<para>
Consider the differences between a column with a default and a generated
column. The column default is evaluated once when the row is first
inserted if no other value was provided; a generated column is updated
whenever the row changes and cannot be overridden. A column default may
not refer to other columns of the table; a generation expression would
normally do so. A column default can use volatile functions, for example
<literal>random()</literal> or functions referring to the current time;
this is not allowed for generated columns.
</para>
<para>
Several restrictions apply to the definition of generated columns and
tables involving generated columns:
<itemizedlist>
<listitem>
<para>
The generation expression can only use immutable functions and cannot
use subqueries or reference anything other than the current row in any
way.
</para>
</listitem>
<listitem>
<para>
A generation expression cannot reference another generated column.
</para>
</listitem>
<listitem>
<para>
A generation expression cannot reference a system column, except
<varname>tableoid</varname>.
</para>
</listitem>
<listitem>
<para>
A generated column cannot have a column default or an identity definition.
</para>
</listitem>
<listitem>
<para>
A generated column cannot be part of a partition key.
</para>
</listitem>
<listitem>
<para>
Foreign tables can have generated columns. See <xref
linkend="sql-createforeigntable"/> for details.
</para>
</listitem>
<listitem>
<para>For inheritance:</para>
<itemizedlist>
<listitem>
<para>
If a parent column is a generated column, a child column must also be
a generated column using the same expression. In the definition of
the child column, leave off the <literal>GENERATED</literal> clause,
as it will be copied from the parent.
</para>
</listitem>
<listitem>
<para>
In case of multiple inheritance, if one parent column is a generated
column, then all parent columns must be generated columns and with the
same expression.
</para>
</listitem>
<listitem>
<para>
If a parent column is not a generated column, a child column may be
defined to be a generated column or not.
</para>
</listitem>
</itemizedlist>
</listitem>
</itemizedlist>
</para>
<para>
Additional considerations apply to the use of generated columns.
<itemizedlist>
<listitem>
<para>
Generated columns maintain access privileges separately from their
underlying base columns. So, it is possible to arrange it so that a
particular role can read from a generated column but not from the
underlying base columns.
</para>
</listitem>
<listitem>
<para>
Generated columns are, conceptually, updated after
<literal>BEFORE</literal> triggers have run. Therefore, changes made to
base columns in a <literal>BEFORE</literal> trigger will be reflected in
generated columns. But conversely, it is not allowed to access
generated columns in <literal>BEFORE</literal> triggers.
</para>
</listitem>
</itemizedlist>
</para>
</sect1>
<sect1 id="ddl-constraints">
<title>Constraints</title>
<indexterm zone="ddl-constraints">
<primary>constraint</primary>
</indexterm>
<para>
Data types are a way to limit the kind of data that can be stored
in a table. For many applications, however, the constraint they
provide is too coarse. For example, a column containing a product
price should probably only accept positive values. But there is no
standard data type that accepts only positive numbers. Another issue is
that you might want to constrain column data with respect to other
columns or rows. For example, in a table containing product
information, there should be only one row for each product number.
</para>
<para>
To that end, SQL allows you to define constraints on columns and
tables. Constraints give you as much control over the data in your
tables as you wish. If a user attempts to store data in a column
that would violate a constraint, an error is raised. This applies
even if the value came from the default value definition.
</para>
<sect2 id="ddl-constraints-check-constraints">
<title>Check Constraints</title>
<indexterm>
<primary>check constraint</primary>
</indexterm>
<indexterm>
<primary>constraint</primary>
<secondary>check</secondary>
</indexterm>
<para>
A check constraint is the most generic constraint type. It allows
you to specify that the value in a certain column must satisfy a
Boolean (truth-value) expression. For instance, to require positive
product prices, you could use:
<programlisting>
CREATE TABLE products (
product_no integer,
name text,
price numeric <emphasis>CHECK (price > 0)</emphasis>
);
</programlisting>
</para>
<para>
As you see, the constraint definition comes after the data type,
just like default value definitions. Default values and
constraints can be listed in any order. A check constraint
consists of the key word <literal>CHECK</literal> followed by an
expression in parentheses. The check constraint expression should
involve the column thus constrained, otherwise the constraint
would not make too much sense.
</para>
<indexterm>
<primary>constraint</primary>
<secondary>name</secondary>
</indexterm>
<para>
You can also give the constraint a separate name. This clarifies
error messages and allows you to refer to the constraint when you
need to change it. The syntax is:
<programlisting>
CREATE TABLE products (
product_no integer,
name text,
price numeric <emphasis>CONSTRAINT positive_price</emphasis> CHECK (price > 0)
);
</programlisting>
So, to specify a named constraint, use the key word
<literal>CONSTRAINT</literal> followed by an identifier followed
by the constraint definition. (If you don't specify a constraint
name in this way, the system chooses a name for you.)
</para>
<para>
A check constraint can also refer to several columns. Say you
store a regular price and a discounted price, and you want to
ensure that the discounted price is lower than the regular price:
<programlisting>
CREATE TABLE products (
product_no integer,
name text,
price numeric CHECK (price > 0),
discounted_price numeric CHECK (discounted_price > 0),
<emphasis>CHECK (price > discounted_price)</emphasis>
);
</programlisting>
</para>
<para>
The first two constraints should look familiar. The third one
uses a new syntax. It is not attached to a particular column,
instead it appears as a separate item in the comma-separated
column list. Column definitions and these constraint
definitions can be listed in mixed order.
</para>
<para>
We say that the first two constraints are column constraints, whereas the
third one is a table constraint because it is written separately
from any one column definition. Column constraints can also be
written as table constraints, while the reverse is not necessarily
possible, since a column constraint is supposed to refer to only the
column it is attached to. (<productname>PostgreSQL</productname> doesn't
enforce that rule, but you should follow it if you want your table
definitions to work with other database systems.) The above example could
also be written as:
<programlisting>
CREATE TABLE products (
product_no integer,
name text,
price numeric,
CHECK (price > 0),
discounted_price numeric,
CHECK (discounted_price > 0),
CHECK (price > discounted_price)
);
</programlisting>
or even:
<programlisting>
CREATE TABLE products (
product_no integer,
name text,
price numeric CHECK (price > 0),
discounted_price numeric,
CHECK (discounted_price > 0 AND price > discounted_price)
);
</programlisting>
It's a matter of taste.
</para>
<para>
Names can be assigned to table constraints in the same way as
column constraints:
<programlisting>
CREATE TABLE products (
product_no integer,
name text,
price numeric,
CHECK (price > 0),
discounted_price numeric,
CHECK (discounted_price > 0),
<emphasis>CONSTRAINT valid_discount</emphasis> CHECK (price > discounted_price)
);
</programlisting>
</para>
<indexterm>
<primary>null value</primary>
<secondary sortas="check constraints">with check constraints</secondary>
</indexterm>
<para>
It should be noted that a check constraint is satisfied if the
check expression evaluates to true or the null value. Since most
expressions will evaluate to the null value if any operand is null,
they will not prevent null values in the constrained columns. To
ensure that a column does not contain null values, the not-null
constraint described in the next section can be used.
</para>
<note>
<para>
<productname>PostgreSQL</productname> does not support
<literal>CHECK</literal> constraints that reference table data other than
the new or updated row being checked. While a <literal>CHECK</literal>
constraint that violates this rule may appear to work in simple
tests, it cannot guarantee that the database will not reach a state
in which the constraint condition is false (due to subsequent changes
of the other row(s) involved). This would cause a database dump and
restore to fail. The restore could fail even when the complete
database state is consistent with the constraint, due to rows not
being loaded in an order that will satisfy the constraint. If
possible, use <literal>UNIQUE</literal>, <literal>EXCLUDE</literal>,
or <literal>FOREIGN KEY</literal> constraints to express
cross-row and cross-table restrictions.
</para>
<para>
If what you desire is a one-time check against other rows at row
insertion, rather than a continuously-maintained consistency
guarantee, a custom <link linkend="triggers">trigger</link> can be used
to implement that. (This approach avoids the dump/restore problem because
<application>pg_dump</application> does not reinstall triggers until after
restoring data, so that the check will not be enforced during a
dump/restore.)
</para>
</note>
<note>
<para>
<productname>PostgreSQL</productname> assumes that
<literal>CHECK</literal> constraints' conditions are immutable, that
is, they will always give the same result for the same input row.
This assumption is what justifies examining <literal>CHECK</literal>
constraints only when rows are inserted or updated, and not at other
times. (The warning above about not referencing other table data is
really a special case of this restriction.)
</para>
<para>
An example of a common way to break this assumption is to reference a
user-defined function in a <literal>CHECK</literal> expression, and
then change the behavior of that
function. <productname>PostgreSQL</productname> does not disallow
that, but it will not notice if there are rows in the table that now
violate the <literal>CHECK</literal> constraint. That would cause a
subsequent database dump and restore to fail.
The recommended way to handle such a change is to drop the constraint
(using <command>ALTER TABLE</command>), adjust the function definition,
and re-add the constraint, thereby rechecking it against all table rows.
</para>
</note>
</sect2>
<sect2>
<title>Not-Null Constraints</title>
<indexterm>
<primary>not-null constraint</primary>
</indexterm>
<indexterm>
<primary>constraint</primary>
<secondary>NOT NULL</secondary>
</indexterm>
<para>
A not-null constraint simply specifies that a column must not
assume the null value. A syntax example:
<programlisting>
CREATE TABLE products (
product_no integer <emphasis>NOT NULL</emphasis>,
name text <emphasis>NOT NULL</emphasis>,
price numeric
);
</programlisting>
</para>
<para>
A not-null constraint is always written as a column constraint. A
not-null constraint is functionally equivalent to creating a check
constraint <literal>CHECK (<replaceable>column_name</replaceable>
IS NOT NULL)</literal>, but in
<productname>PostgreSQL</productname> creating an explicit
not-null constraint is more efficient. The drawback is that you
cannot give explicit names to not-null constraints created this
way.
</para>
<para>
Of course, a column can have more than one constraint. Just write
the constraints one after another:
<programlisting>
CREATE TABLE products (
product_no integer NOT NULL,
name text NOT NULL,
price numeric NOT NULL CHECK (price > 0)
);
</programlisting>
The order doesn't matter. It does not necessarily determine in which
order the constraints are checked.
</para>
<para>
The <literal>NOT NULL</literal> constraint has an inverse: the
<literal>NULL</literal> constraint. This does not mean that the
column must be null, which would surely be useless. Instead, this
simply selects the default behavior that the column might be null.
The <literal>NULL</literal> constraint is not present in the SQL
standard and should not be used in portable applications. (It was
only added to <productname>PostgreSQL</productname> to be
compatible with some other database systems.) Some users, however,
like it because it makes it easy to toggle the constraint in a
script file. For example, you could start with:
<programlisting>
CREATE TABLE products (
product_no integer NULL,
name text NULL,
price numeric NULL
);
</programlisting>
and then insert the <literal>NOT</literal> key word where desired.
</para>
<tip>
<para>
In most database designs the majority of columns should be marked
not null.
</para>
</tip>
</sect2>
<sect2 id="ddl-constraints-unique-constraints">
<title>Unique Constraints</title>
<indexterm>
<primary>unique constraint</primary>
</indexterm>
<indexterm>
<primary>constraint</primary>
<secondary>unique</secondary>
</indexterm>
<para>
Unique constraints ensure that the data contained in a column, or a
group of columns, is unique among all the rows in the
table. The syntax is:
<programlisting>
CREATE TABLE products (
product_no integer <emphasis>UNIQUE</emphasis>,
name text,
price numeric
);
</programlisting>
when written as a column constraint, and:
<programlisting>
CREATE TABLE products (
product_no integer,
name text,
price numeric,
<emphasis>UNIQUE (product_no)</emphasis>
);
</programlisting>
when written as a table constraint.
</para>
<para>
To define a unique constraint for a group of columns, write it as a
table constraint with the column names separated by commas:
<programlisting>
CREATE TABLE example (
a integer,
b integer,
c integer,
<emphasis>UNIQUE (a, c)</emphasis>
);
</programlisting>
This specifies that the combination of values in the indicated columns
is unique across the whole table, though any one of the columns
need not be (and ordinarily isn't) unique.
</para>
<para>
You can assign your own name for a unique constraint, in the usual way:
<programlisting>
CREATE TABLE products (
product_no integer <emphasis>CONSTRAINT must_be_different</emphasis> UNIQUE,
name text,
price numeric
);
</programlisting>
</para>
<para>
Adding a unique constraint will automatically create a unique B-tree
index on the column or group of columns listed in the constraint.
A uniqueness restriction covering only some rows cannot be written as
a unique constraint, but it is possible to enforce such a restriction by
creating a unique <link linkend="indexes-partial">partial index</link>.
</para>
<indexterm>
<primary>null value</primary>
<secondary sortas="unique constraints">with unique constraints</secondary>
</indexterm>
<para>
In general, a unique constraint is violated if there is more than
one row in the table where the values of all of the
columns included in the constraint are equal.
However, two null values are never considered equal in this
comparison. That means even in the presence of a
unique constraint it is possible to store duplicate
rows that contain a null value in at least one of the constrained
columns. This behavior conforms to the SQL standard, but we have
heard that other SQL databases might not follow this rule. So be
careful when developing applications that are intended to be
portable.
</para>
</sect2>
<sect2 id="ddl-constraints-primary-keys">
<title>Primary Keys</title>
<indexterm>
<primary>primary key</primary>
</indexterm>
<indexterm>
<primary>constraint</primary>
<secondary>primary key</secondary>
</indexterm>
<para>
A primary key constraint indicates that a column, or group of columns,
can be used as a unique identifier for rows in the table. This
requires that the values be both unique and not null. So, the following
two table definitions accept the same data:
<programlisting>
CREATE TABLE products (
product_no integer UNIQUE NOT NULL,
name text,
price numeric
);
</programlisting>
<programlisting>
CREATE TABLE products (
product_no integer <emphasis>PRIMARY KEY</emphasis>,
name text,
price numeric
);
</programlisting>
</para>
<para>
Primary keys can span more than one column; the syntax
is similar to unique constraints:
<programlisting>
CREATE TABLE example (
a integer,
b integer,
c integer,
<emphasis>PRIMARY KEY (a, c)</emphasis>
);
</programlisting>
</para>
<para>
Adding a primary key will automatically create a unique B-tree index
on the column or group of columns listed in the primary key, and will
force the column(s) to be marked <literal>NOT NULL</literal>.
</para>
<para>
A table can have at most one primary key. (There can be any number
of unique and not-null constraints, which are functionally almost the
same thing, but only one can be identified as the primary key.)
Relational database theory
dictates that every table must have a primary key. This rule is
not enforced by <productname>PostgreSQL</productname>, but it is
usually best to follow it.
</para>
<para>
Primary keys are useful both for
documentation purposes and for client applications. For example,
a GUI application that allows modifying row values probably needs
to know the primary key of a table to be able to identify rows
uniquely. There are also various ways in which the database system
makes use of a primary key if one has been declared; for example,
the primary key defines the default target column(s) for foreign keys
referencing its table.
</para>
</sect2>
<sect2 id="ddl-constraints-fk">
<title>Foreign Keys</title>
<indexterm>
<primary>foreign key</primary>
</indexterm>
<indexterm>
<primary>constraint</primary>
<secondary>foreign key</secondary>
</indexterm>
<indexterm>
<primary>referential integrity</primary>
</indexterm>
<para>
A foreign key constraint specifies that the values in a column (or
a group of columns) must match the values appearing in some row
of another table.
We say this maintains the <firstterm>referential
integrity</firstterm> between two related tables.
</para>
<para>
Say you have the product table that we have used several times already:
<programlisting>
CREATE TABLE products (
product_no integer PRIMARY KEY,
name text,
price numeric
);
</programlisting>
Let's also assume you have a table storing orders of those
products. We want to ensure that the orders table only contains
orders of products that actually exist. So we define a foreign
key constraint in the orders table that references the products
table:
<programlisting>
CREATE TABLE orders (
order_id integer PRIMARY KEY,
product_no integer <emphasis>REFERENCES products (product_no)</emphasis>,
quantity integer
);
</programlisting>
Now it is impossible to create orders with non-NULL
<structfield>product_no</structfield> entries that do not appear in the
products table.
</para>
<para>
We say that in this situation the orders table is the
<firstterm>referencing</firstterm> table and the products table is
the <firstterm>referenced</firstterm> table. Similarly, there are
referencing and referenced columns.
</para>
<para>
You can also shorten the above command to:
<programlisting>
CREATE TABLE orders (
order_id integer PRIMARY KEY,
product_no integer <emphasis>REFERENCES products</emphasis>,
quantity integer
);
</programlisting>
because in absence of a column list the primary key of the
referenced table is used as the referenced column(s).
</para>
<para>
You can assign your own name for a foreign key constraint,
in the usual way.
</para>
<para>
A foreign key can also constrain and reference a group of columns.
As usual, it then needs to be written in table constraint form.
Here is a contrived syntax example:
<programlisting>
CREATE TABLE t1 (
a integer PRIMARY KEY,
b integer,
c integer,
<emphasis>FOREIGN KEY (b, c) REFERENCES other_table (c1, c2)</emphasis>
);
</programlisting>
Of course, the number and type of the constrained columns need to
match the number and type of the referenced columns.
</para>
<indexterm>
<primary>foreign key</primary>
<secondary>self-referential</secondary>
</indexterm>
<para>
Sometimes it is useful for the <quote>other table</quote> of a
foreign key constraint to be the same table; this is called
a <firstterm>self-referential</firstterm> foreign key. For
example, if you want rows of a table to represent nodes of a tree
structure, you could write
<programlisting>
CREATE TABLE tree (
node_id integer PRIMARY KEY,
parent_id integer REFERENCES tree,
name text,
...
);
</programlisting>
A top-level node would have NULL <structfield>parent_id</structfield>,
while non-NULL <structfield>parent_id</structfield> entries would be
constrained to reference valid rows of the table.
</para>
<para>
A table can have more than one foreign key constraint. This is
used to implement many-to-many relationships between tables. Say
you have tables about products and orders, but now you want to
allow one order to contain possibly many products (which the
structure above did not allow). You could use this table structure:
<programlisting>
CREATE TABLE products (
product_no integer PRIMARY KEY,
name text,
price numeric
);
CREATE TABLE orders (
order_id integer PRIMARY KEY,
shipping_address text,
...
);
CREATE TABLE order_items (
product_no integer REFERENCES products,
order_id integer REFERENCES orders,
quantity integer,
PRIMARY KEY (product_no, order_id)
);
</programlisting>
Notice that the primary key overlaps with the foreign keys in
the last table.
</para>
<indexterm>
<primary>CASCADE</primary>
<secondary>foreign key action</secondary>
</indexterm>
<indexterm>
<primary>RESTRICT</primary>
<secondary>foreign key action</secondary>
</indexterm>
<para>
We know that the foreign keys disallow creation of orders that
do not relate to any products. But what if a product is removed
after an order is created that references it? SQL allows you to
handle that as well. Intuitively, we have a few options:
<itemizedlist spacing="compact">
<listitem><para>Disallow deleting a referenced product</para></listitem>
<listitem><para>Delete the orders as well</para></listitem>
<listitem><para>Something else?</para></listitem>
</itemizedlist>
</para>
<para>
To illustrate this, let's implement the following policy on the
many-to-many relationship example above: when someone wants to
remove a product that is still referenced by an order (via
<literal>order_items</literal>), we disallow it. If someone
removes an order, the order items are removed as well:
<programlisting>
CREATE TABLE products (
product_no integer PRIMARY KEY,
name text,
price numeric
);
CREATE TABLE orders (
order_id integer PRIMARY KEY,
shipping_address text,
...
);
CREATE TABLE order_items (
product_no integer REFERENCES products <emphasis>ON DELETE RESTRICT</emphasis>,
order_id integer REFERENCES orders <emphasis>ON DELETE CASCADE</emphasis>,
quantity integer,
PRIMARY KEY (product_no, order_id)
);
</programlisting>
</para>
<para>
Restricting and cascading deletes are the two most common options.
<literal>RESTRICT</literal> prevents deletion of a
referenced row. <literal>NO ACTION</literal> means that if any
referencing rows still exist when the constraint is checked, an error
is raised; this is the default behavior if you do not specify anything.
(The essential difference between these two choices is that
<literal>NO ACTION</literal> allows the check to be deferred until
later in the transaction, whereas <literal>RESTRICT</literal> does not.)
<literal>CASCADE</literal> specifies that when a referenced row is deleted,
row(s) referencing it should be automatically deleted as well.
There are two other options:
<literal>SET NULL</literal> and <literal>SET DEFAULT</literal>.
These cause the referencing column(s) in the referencing row(s)
to be set to nulls or their default
values, respectively, when the referenced row is deleted.
Note that these do not excuse you from observing any constraints.
For example, if an action specifies <literal>SET DEFAULT</literal>
but the default value would not satisfy the foreign key constraint, the
operation will fail.
</para>
<para>
Analogous to <literal>ON DELETE</literal> there is also
<literal>ON UPDATE</literal> which is invoked when a referenced
column is changed (updated). The possible actions are the same.
In this case, <literal>CASCADE</literal> means that the updated values of the
referenced column(s) should be copied into the referencing row(s).
</para>
<para>
Normally, a referencing row need not satisfy the foreign key constraint
if any of its referencing columns are null. If <literal>MATCH FULL</literal>
is added to the foreign key declaration, a referencing row escapes
satisfying the constraint only if all its referencing columns are null
(so a mix of null and non-null values is guaranteed to fail a
<literal>MATCH FULL</literal> constraint). If you don't want referencing rows
to be able to avoid satisfying the foreign key constraint, declare the
referencing column(s) as <literal>NOT NULL</literal>.
</para>
<para>
A foreign key must reference columns that either are a primary key or
form a unique constraint. This means that the referenced columns always
have an index (the one underlying the primary key or unique constraint);
so checks on whether a referencing row has a match will be efficient.
Since a <command>DELETE</command> of a row from the referenced table
or an <command>UPDATE</command> of a referenced column will require
a scan of the referencing table for rows matching the old value, it
is often a good idea to index the referencing columns too. Because this
is not always needed, and there are many choices available on how
to index, declaration of a foreign key constraint does not
automatically create an index on the referencing columns.
</para>
<para>
More information about updating and deleting data is in <xref
linkend="dml"/>. Also see the description of foreign key constraint
syntax in the reference documentation for
<xref linkend="sql-createtable"/>.
</para>
</sect2>
<sect2 id="ddl-constraints-exclusion">
<title>Exclusion Constraints</title>
<indexterm>
<primary>exclusion constraint</primary>
</indexterm>
<indexterm>
<primary>constraint</primary>
<secondary>exclusion</secondary>
</indexterm>
<para>
Exclusion constraints ensure that if any two rows are compared on
the specified columns or expressions using the specified operators,
at least one of these operator comparisons will return false or null.
The syntax is:
<programlisting>
CREATE TABLE circles (
c circle,
EXCLUDE USING gist (c WITH &&)
);
</programlisting>
</para>
<para>
See also <link linkend="sql-createtable-exclude"><command>CREATE
TABLE ... CONSTRAINT ... EXCLUDE</command></link> for details.
</para>
<para>
Adding an exclusion constraint will automatically create an index
of the type specified in the constraint declaration.
</para>
</sect2>
</sect1>
<sect1 id="ddl-system-columns">
<title>System Columns</title>
<para>
Every table has several <firstterm>system columns</firstterm> that are
implicitly defined by the system. Therefore, these names cannot be
used as names of user-defined columns. (Note that these
restrictions are separate from whether the name is a key word or
not; quoting a name will not allow you to escape these
restrictions.) You do not really need to be concerned about these
columns; just know they exist.
</para>
<indexterm>
<primary>column</primary>
<secondary>system column</secondary>
</indexterm>
<variablelist>
<varlistentry>
<term><structfield>tableoid</structfield></term>
<listitem>
<indexterm>
<primary>tableoid</primary>
</indexterm>
<para>
The OID of the table containing this row. This column is
particularly handy for queries that select from partitioned
tables (see <xref linkend="ddl-partitioning"/>) or inheritance
hierarchies (see <xref linkend="ddl-inherit"/>), since without it,
it's difficult to tell which individual table a row came from. The
<structfield>tableoid</structfield> can be joined against the
<structfield>oid</structfield> column of
<structname>pg_class</structname> to obtain the table name.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><structfield>xmin</structfield></term>
<listitem>
<indexterm>
<primary>xmin</primary>
</indexterm>
<para>
The identity (transaction ID) of the inserting transaction for
this row version. (A row version is an individual state of a
row; each update of a row creates a new row version for the same
logical row.)
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><structfield>cmin</structfield></term>
<listitem>
<indexterm>
<primary>cmin</primary>
</indexterm>
<para>
The command identifier (starting at zero) within the inserting
transaction.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><structfield>xmax</structfield></term>
<listitem>
<indexterm>
<primary>xmax</primary>
</indexterm>
<para>
The identity (transaction ID) of the deleting transaction, or
zero for an undeleted row version. It is possible for this column to
be nonzero in a visible row version. That usually indicates that the
deleting transaction hasn't committed yet, or that an attempted
deletion was rolled back.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><structfield>cmax</structfield></term>
<listitem>
<indexterm>
<primary>cmax</primary>
</indexterm>
<para>
The command identifier within the deleting transaction, or zero.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><structfield>ctid</structfield></term>
<listitem>
<indexterm>
<primary>ctid</primary>
</indexterm>
<para>
The physical location of the row version within its table. Note that
although the <structfield>ctid</structfield> can be used to
locate the row version very quickly, a row's
<structfield>ctid</structfield> will change if it is
updated or moved by <command>VACUUM FULL</command>. Therefore
<structfield>ctid</structfield> is useless as a long-term row
identifier. A primary key should be used to identify logical rows.
</para>
</listitem>
</varlistentry>
</variablelist>
<para>
Transaction identifiers are also 32-bit quantities. In a
long-lived database it is possible for transaction IDs to wrap
around. This is not a fatal problem given appropriate maintenance
procedures; see <xref linkend="maintenance"/> for details. It is
unwise, however, to depend on the uniqueness of transaction IDs
over the long term (more than one billion transactions).
</para>
<para>
Command identifiers are also 32-bit quantities. This creates a hard limit
of 2<superscript>32</superscript> (4 billion) <acronym>SQL</acronym> commands
within a single transaction. In practice this limit is not a
problem — note that the limit is on the number of
<acronym>SQL</acronym> commands, not the number of rows processed.
Also, only commands that actually modify the database contents will
consume a command identifier.
</para>
</sect1>
<sect1 id="ddl-alter">
<title>Modifying Tables</title>
<indexterm zone="ddl-alter">
<primary>table</primary>
<secondary>modifying</secondary>
</indexterm>
<para>
When you create a table and you realize that you made a mistake, or
the requirements of the application change, you can drop the
table and create it again. But this is not a convenient option if
the table is already filled with data, or if the table is
referenced by other database objects (for instance a foreign key
constraint). Therefore <productname>PostgreSQL</productname>
provides a family of commands to make modifications to existing
tables. Note that this is conceptually distinct from altering
the data contained in the table: here we are interested in altering
the definition, or structure, of the table.
</para>
<para>
You can:
<itemizedlist spacing="compact">
<listitem>
<para>Add columns</para>
</listitem>
<listitem>
<para>Remove columns</para>
</listitem>
<listitem>
<para>Add constraints</para>
</listitem>
<listitem>
<para>Remove constraints</para>
</listitem>
<listitem>
<para>Change default values</para>
</listitem>
<listitem>
<para>Change column data types</para>
</listitem>
<listitem>
<para>Rename columns</para>
</listitem>
<listitem>
<para>Rename tables</para>
</listitem>
</itemizedlist>
All these actions are performed using the
<xref linkend="sql-altertable"/>
command, whose reference page contains details beyond those given
here.
</para>
<sect2 id="ddl-alter-adding-a-column">
<title>Adding a Column</title>
<indexterm>
<primary>column</primary>
<secondary>adding</secondary>
</indexterm>
<para>
To add a column, use a command like:
<programlisting>
ALTER TABLE products ADD COLUMN description text;
</programlisting>
The new column is initially filled with whatever default
value is given (null if you don't specify a <literal>DEFAULT</literal> clause).
</para>
<tip>
<para>
From <productname>PostgreSQL</productname> 11, adding a column with
a constant default value no longer means that each row of the table
needs to be updated when the <command>ALTER TABLE</command> statement
is executed. Instead, the default value will be returned the next time
the row is accessed, and applied when the table is rewritten, making
the <command>ALTER TABLE</command> very fast even on large tables.
</para>
<para>
However, if the default value is volatile (e.g.,
<function>clock_timestamp()</function>)
each row will need to be updated with the value calculated at the time
<command>ALTER TABLE</command> is executed. To avoid a potentially
lengthy update operation, particularly if you intend to fill the column
with mostly nondefault values anyway, it may be preferable to add the
column with no default, insert the correct values using
<command>UPDATE</command>, and then add any desired default as described
below.
</para>
</tip>
<para>
You can also define constraints on the column at the same time,
using the usual syntax:
<programlisting>
ALTER TABLE products ADD COLUMN description text CHECK (description <> '');
</programlisting>
In fact all the options that can be applied to a column description
in <command>CREATE TABLE</command> can be used here. Keep in mind however
that the default value must satisfy the given constraints, or the
<literal>ADD</literal> will fail. Alternatively, you can add
constraints later (see below) after you've filled in the new column
correctly.
</para>
</sect2>
<sect2 id="ddl-alter-removing-a-column">
<title>Removing a Column</title>
<indexterm>
<primary>column</primary>
<secondary>removing</secondary>
</indexterm>
<para>
To remove a column, use a command like:
<programlisting>
ALTER TABLE products DROP COLUMN description;
</programlisting>
Whatever data was in the column disappears. Table constraints involving
the column are dropped, too. However, if the column is referenced by a
foreign key constraint of another table,
<productname>PostgreSQL</productname> will not silently drop that
constraint. You can authorize dropping everything that depends on
the column by adding <literal>CASCADE</literal>:
<programlisting>
ALTER TABLE products DROP COLUMN description CASCADE;
</programlisting>
See <xref linkend="ddl-depend"/> for a description of the general
mechanism behind this.
</para>
</sect2>
<sect2 id="ddl-alter-adding-a-constraint">
<title>Adding a Constraint</title>
<indexterm>
<primary>constraint</primary>
<secondary>adding</secondary>
</indexterm>
<para>
To add a constraint, the table constraint syntax is used. For example:
<programlisting>
ALTER TABLE products ADD CHECK (name <> '');
ALTER TABLE products ADD CONSTRAINT some_name UNIQUE (product_no);
ALTER TABLE products ADD FOREIGN KEY (product_group_id) REFERENCES product_groups;
</programlisting>
To add a not-null constraint, which cannot be written as a table
constraint, use this syntax:
<programlisting>
ALTER TABLE products ALTER COLUMN product_no SET NOT NULL;
</programlisting>
</para>
<para>
The constraint will be checked immediately, so the table data must
satisfy the constraint before it can be added.
</para>
</sect2>
<sect2 id="ddl-alter-removing-a-constraint">
<title>Removing a Constraint</title>
<indexterm>
<primary>constraint</primary>
<secondary>removing</secondary>
</indexterm>
<para>
To remove a constraint you need to know its name. If you gave it
a name then that's easy. Otherwise the system assigned a
generated name, which you need to find out. The
<application>psql</application> command <literal>\d
<replaceable>tablename</replaceable></literal> can be helpful
here; other interfaces might also provide a way to inspect table
details. Then the command is:
<programlisting>
ALTER TABLE products DROP CONSTRAINT some_name;
</programlisting>
(If you are dealing with a generated constraint name like <literal>$2</literal>,
don't forget that you'll need to double-quote it to make it a valid
identifier.)
</para>
<para>
As with dropping a column, you need to add <literal>CASCADE</literal> if you
want to drop a constraint that something else depends on. An example
is that a foreign key constraint depends on a unique or primary key
constraint on the referenced column(s).
</para>
<para>
This works the same for all constraint types except not-null
constraints. To drop a not null constraint use:
<programlisting>
ALTER TABLE products ALTER COLUMN product_no DROP NOT NULL;
</programlisting>
(Recall that not-null constraints do not have names.)
</para>
</sect2>
<sect2>
<title>Changing a Column's Default Value</title>
<indexterm>
<primary>default value</primary>
<secondary>changing</secondary>
</indexterm>
<para>
To set a new default for a column, use a command like:
<programlisting>
ALTER TABLE products ALTER COLUMN price SET DEFAULT 7.77;
</programlisting>
Note that this doesn't affect any existing rows in the table, it
just changes the default for future <command>INSERT</command> commands.
</para>
<para>
To remove any default value, use:
<programlisting>
ALTER TABLE products ALTER COLUMN price DROP DEFAULT;
</programlisting>
This is effectively the same as setting the default to null.
As a consequence, it is not an error
to drop a default where one hadn't been defined, because the
default is implicitly the null value.
</para>
</sect2>
<sect2>
<title>Changing a Column's Data Type</title>
<indexterm>
<primary>column data type</primary>
<secondary>changing</secondary>
</indexterm>
<para>
To convert a column to a different data type, use a command like:
<programlisting>
ALTER TABLE products ALTER COLUMN price TYPE numeric(10,2);
</programlisting>
This will succeed only if each existing entry in the column can be
converted to the new type by an implicit cast. If a more complex
conversion is needed, you can add a <literal>USING</literal> clause that
specifies how to compute the new values from the old.
</para>
<para>
<productname>PostgreSQL</productname> will attempt to convert the column's
default value (if any) to the new type, as well as any constraints
that involve the column. But these conversions might fail, or might
produce surprising results. It's often best to drop any constraints
on the column before altering its type, and then add back suitably
modified constraints afterwards.
</para>
</sect2>
<sect2>
<title>Renaming a Column</title>
<indexterm>
<primary>column</primary>
<secondary>renaming</secondary>
</indexterm>
<para>
To rename a column:
<programlisting>
ALTER TABLE products RENAME COLUMN product_no TO product_number;
</programlisting>
</para>
</sect2>
<sect2>
<title>Renaming a Table</title>
<indexterm>
<primary>table</primary>
<secondary>renaming</secondary>
</indexterm>
<para>
To rename a table:
<programlisting>
ALTER TABLE products RENAME TO items;
</programlisting>
</para>
</sect2>
</sect1>
<sect1 id="ddl-priv">
<title>Privileges</title>
<indexterm zone="ddl-priv">
<primary>privilege</primary>
</indexterm>
<indexterm>
<primary>permission</primary>
<see>privilege</see>
</indexterm>
<indexterm zone="ddl-priv">
<primary>owner</primary>
</indexterm>
<indexterm zone="ddl-priv">
<primary>GRANT</primary>
</indexterm>
<indexterm zone="ddl-priv">
<primary>REVOKE</primary>
</indexterm>
<indexterm zone="ddl-priv">
<primary>ACL</primary>
</indexterm>
<para>
When an object is created, it is assigned an owner. The
owner is normally the role that executed the creation statement.
For most kinds of objects, the initial state is that only the owner
(or a superuser) can do anything with the object. To allow
other roles to use it, <firstterm>privileges</firstterm> must be
granted.
</para>
<para>
There are different kinds of privileges: <literal>SELECT</literal>,
<literal>INSERT</literal>, <literal>UPDATE</literal>, <literal>DELETE</literal>,
<literal>TRUNCATE</literal>, <literal>REFERENCES</literal>, <literal>TRIGGER</literal>,
<literal>CREATE</literal>, <literal>CONNECT</literal>, <literal>TEMPORARY</literal>,
<literal>EXECUTE</literal>, and <literal>USAGE</literal>.
The privileges applicable to a particular
object vary depending on the object's type (table, function, etc).
More detail about the meanings of these privileges appears below.
The following sections and chapters will also show you how
these privileges are used.
</para>
<para>
The right to modify or destroy an object is inherent in being the
object's owner, and cannot be granted or revoked in itself.
(However, like all privileges, that right can be inherited by
members of the owning role; see <xref linkend="role-membership"/>.)
</para>
<para>
An object can be assigned to a new owner with an <command>ALTER</command>
command of the appropriate kind for the object, for example
<programlisting>
ALTER TABLE <replaceable>table_name</replaceable> OWNER TO <replaceable>new_owner</replaceable>;
</programlisting>
Superusers can always do this; ordinary roles can only do it if they are
both the current owner of the object (or a member of the owning role) and
a member of the new owning role.
</para>
<para>
To assign privileges, the <xref linkend="sql-grant"/> command is
used. For example, if <literal>joe</literal> is an existing role, and
<literal>accounts</literal> is an existing table, the privilege to
update the table can be granted with:
<programlisting>
GRANT UPDATE ON accounts TO joe;
</programlisting>
Writing <literal>ALL</literal> in place of a specific privilege grants all
privileges that are relevant for the object type.
</para>
<para>
The special <quote>role</quote> name <literal>PUBLIC</literal> can
be used to grant a privilege to every role on the system. Also,
<quote>group</quote> roles can be set up to help manage privileges when
there are many users of a database — for details see
<xref linkend="user-manag"/>.
</para>
<para>
To revoke a previously-granted privilege, use the fittingly named
<xref linkend="sql-revoke"/> command:
<programlisting>
REVOKE ALL ON accounts FROM PUBLIC;
</programlisting>
</para>
<para>
Ordinarily, only the object's owner (or a superuser) can grant or
revoke privileges on an object. However, it is possible to grant a
privilege <quote>with grant option</quote>, which gives the recipient
the right to grant it in turn to others. If the grant option is
subsequently revoked then all who received the privilege from that
recipient (directly or through a chain of grants) will lose the
privilege. For details see the <xref linkend="sql-grant"/> and
<xref linkend="sql-revoke"/> reference pages.
</para>
<para>
An object's owner can choose to revoke their own ordinary privileges,
for example to make a table read-only for themselves as well as others.
But owners are always treated as holding all grant options, so they
can always re-grant their own privileges.
</para>
<para>
The available privileges are:
<variablelist>
<varlistentry>
<term><literal>SELECT</literal></term>
<listitem>
<para>
Allows <command>SELECT</command> from
any column, or specific column(s), of a table, view, materialized
view, or other table-like object.
Also allows use of <command>COPY TO</command>.
This privilege is also needed to reference existing column values in
<command>UPDATE</command> or <command>DELETE</command>.
For sequences, this privilege also allows use of the
<function>currval</function> function.
For large objects, this privilege allows the object to be read.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>INSERT</literal></term>
<listitem>
<para>
Allows <command>INSERT</command> of a new row into a table, view,
etc. Can be granted on specific column(s), in which case
only those columns may be assigned to in the <command>INSERT</command>
command (other columns will therefore receive default values).
Also allows use of <command>COPY FROM</command>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>UPDATE</literal></term>
<listitem>
<para>
Allows <command>UPDATE</command> of any
column, or specific column(s), of a table, view, etc.
(In practice, any nontrivial <command>UPDATE</command> command will
require <literal>SELECT</literal> privilege as well, since it must
reference table columns to determine which rows to update, and/or to
compute new values for columns.)
<literal>SELECT ... FOR UPDATE</literal>
and <literal>SELECT ... FOR SHARE</literal>
also require this privilege on at least one column, in addition to the
<literal>SELECT</literal> privilege. For sequences, this
privilege allows use of the <function>nextval</function> and
<function>setval</function> functions.
For large objects, this privilege allows writing or truncating the
object.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>DELETE</literal></term>
<listitem>
<para>
Allows <command>DELETE</command> of a row from a table, view, etc.
(In practice, any nontrivial <command>DELETE</command> command will
require <literal>SELECT</literal> privilege as well, since it must
reference table columns to determine which rows to delete.)
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>TRUNCATE</literal></term>
<listitem>
<para>
Allows <command>TRUNCATE</command> on a table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>REFERENCES</literal></term>
<listitem>
<para>
Allows creation of a foreign key constraint referencing a
table, or specific column(s) of a table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>TRIGGER</literal></term>
<listitem>
<para>
Allows creation of a trigger on a table, view, etc.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>CREATE</literal></term>
<listitem>
<para>
For databases, allows new schemas and publications to be created within
the database, and allows trusted extensions to be installed within
the database.
</para>
<para>
For schemas, allows new objects to be created within the schema.
To rename an existing object, you must own the
object <emphasis>and</emphasis> have this privilege for the containing
schema.
</para>
<para>
For tablespaces, allows tables, indexes, and temporary files to be
created within the tablespace, and allows databases to be created that
have the tablespace as their default tablespace.
</para>
<para>
Note that revoking this privilege will not alter the existence or
location of existing objects.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>CONNECT</literal></term>
<listitem>
<para>
Allows the grantee to connect to the database. This
privilege is checked at connection startup (in addition to checking
any restrictions imposed by <filename>pg_hba.conf</filename>).
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>TEMPORARY</literal></term>
<listitem>
<para>
Allows temporary tables to be created while using the database.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>EXECUTE</literal></term>
<listitem>
<para>
Allows calling a function or procedure, including use of
any operators that are implemented on top of the function. This is the
only type of privilege that is applicable to functions and procedures.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>USAGE</literal></term>
<listitem>
<para>
For procedural languages, allows use of the language for
the creation of functions in that language. This is the only type
of privilege that is applicable to procedural languages.
</para>
<para>
For schemas, allows access to objects contained in the
schema (assuming that the objects' own privilege requirements are
also met). Essentially this allows the grantee to <quote>look up</quote>
objects within the schema. Without this permission, it is still
possible to see the object names, e.g., by querying system catalogs.
Also, after revoking this permission, existing sessions might have
statements that have previously performed this lookup, so this is not
a completely secure way to prevent object access.
</para>
<para>
For sequences, allows use of the
<function>currval</function> and <function>nextval</function> functions.
</para>
<para>
For types and domains, allows use of the type or domain in the
creation of tables, functions, and other schema objects. (Note that
this privilege does not control all <quote>usage</quote> of the
type, such as values of the type appearing in queries. It only
prevents objects from being created that depend on the type. The
main purpose of this privilege is controlling which users can create
dependencies on a type, which could prevent the owner from changing
the type later.)
</para>
<para>
For foreign-data wrappers, allows creation of new servers using the
foreign-data wrapper.
</para>
<para>
For foreign servers, allows creation of foreign tables using the
server. Grantees may also create, alter, or drop their own user
mappings associated with that server.
</para>
</listitem>
</varlistentry>
</variablelist>
The privileges required by other commands are listed on the
reference page of the respective command.
</para>
<para>
PostgreSQL grants privileges on some types of objects to
<literal>PUBLIC</literal> by default when the objects are created.
No privileges are granted to <literal>PUBLIC</literal> by default on
tables,
table columns,
sequences,
foreign data wrappers,
foreign servers,
large objects,
schemas,
or tablespaces.
For other types of objects, the default privileges
granted to <literal>PUBLIC</literal> are as follows:
<literal>CONNECT</literal> and <literal>TEMPORARY</literal> (create
temporary tables) privileges for databases;
<literal>EXECUTE</literal> privilege for functions and procedures; and
<literal>USAGE</literal> privilege for languages and data types
(including domains).
The object owner can, of course, <command>REVOKE</command>
both default and expressly granted privileges. (For maximum
security, issue the <command>REVOKE</command> in the same transaction that
creates the object; then there is no window in which another user
can use the object.)
Also, these default privilege settings can be overridden using the
<xref linkend="sql-alterdefaultprivileges"/> command.
</para>
<para>
<xref linkend="privilege-abbrevs-table"/> shows the one-letter
abbreviations that are used for these privilege types in
<firstterm>ACL</firstterm> (Access Control List) values.
You will see these letters in the output of the <xref linkend="app-psql"/>
commands listed below, or when looking at ACL columns of system catalogs.
</para>
<table id="privilege-abbrevs-table">
<title>ACL Privilege Abbreviations</title>
<tgroup cols="3">
<colspec colname="col1" colwidth="1*"/>
<colspec colname="col2" colwidth="1*"/>
<colspec colname="col3" colwidth="2*"/>
<thead>
<row>
<entry>Privilege</entry>
<entry>Abbreviation</entry>
<entry>Applicable Object Types</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>SELECT</literal></entry>
<entry><literal>r</literal> (<quote>read</quote>)</entry>
<entry>
<literal>LARGE OBJECT</literal>,
<literal>SEQUENCE</literal>,
<literal>TABLE</literal> (and table-like objects),
table column
</entry>
</row>
<row>
<entry><literal>INSERT</literal></entry>
<entry><literal>a</literal> (<quote>append</quote>)</entry>
<entry><literal>TABLE</literal>, table column</entry>
</row>
<row>
<entry><literal>UPDATE</literal></entry>
<entry><literal>w</literal> (<quote>write</quote>)</entry>
<entry>
<literal>LARGE OBJECT</literal>,
<literal>SEQUENCE</literal>,
<literal>TABLE</literal>,
table column
</entry>
</row>
<row>
<entry><literal>DELETE</literal></entry>
<entry><literal>d</literal></entry>
<entry><literal>TABLE</literal></entry>
</row>
<row>
<entry><literal>TRUNCATE</literal></entry>
<entry><literal>D</literal></entry>
<entry><literal>TABLE</literal></entry>
</row>
<row>
<entry><literal>REFERENCES</literal></entry>
<entry><literal>x</literal></entry>
<entry><literal>TABLE</literal>, table column</entry>
</row>
<row>
<entry><literal>TRIGGER</literal></entry>
<entry><literal>t</literal></entry>
<entry><literal>TABLE</literal></entry>
</row>
<row>
<entry><literal>CREATE</literal></entry>
<entry><literal>C</literal></entry>
<entry>
<literal>DATABASE</literal>,
<literal>SCHEMA</literal>,
<literal>TABLESPACE</literal>
</entry>
</row>
<row>
<entry><literal>CONNECT</literal></entry>
<entry><literal>c</literal></entry>
<entry><literal>DATABASE</literal></entry>
</row>
<row>
<entry><literal>TEMPORARY</literal></entry>
<entry><literal>T</literal></entry>
<entry><literal>DATABASE</literal></entry>
</row>
<row>
<entry><literal>EXECUTE</literal></entry>
<entry><literal>X</literal></entry>
<entry><literal>FUNCTION</literal>, <literal>PROCEDURE</literal></entry>
</row>
<row>
<entry><literal>USAGE</literal></entry>
<entry><literal>U</literal></entry>
<entry>
<literal>DOMAIN</literal>,
<literal>FOREIGN DATA WRAPPER</literal>,
<literal>FOREIGN SERVER</literal>,
<literal>LANGUAGE</literal>,
<literal>SCHEMA</literal>,
<literal>SEQUENCE</literal>,
<literal>TYPE</literal>
</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
<xref linkend="privileges-summary-table"/> summarizes the privileges
available for each type of SQL object, using the abbreviations shown
above.
It also shows the <application>psql</application> command
that can be used to examine privilege settings for each object type.
</para>
<table id="privileges-summary-table">
<title>Summary of Access Privileges</title>
<tgroup cols="4">
<colspec colname="col1" colwidth="2*"/>
<colspec colname="col2" colwidth="1*"/>
<colspec colname="col3" colwidth="1*"/>
<colspec colname="col4" colwidth="1*"/>
<thead>
<row>
<entry>Object Type</entry>
<entry>All Privileges</entry>
<entry>Default <literal>PUBLIC</literal> Privileges</entry>
<entry><application>psql</application> Command</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>DATABASE</literal></entry>
<entry><literal>CTc</literal></entry>
<entry><literal>Tc</literal></entry>
<entry><literal>\l</literal></entry>
</row>
<row>
<entry><literal>DOMAIN</literal></entry>
<entry><literal>U</literal></entry>
<entry><literal>U</literal></entry>
<entry><literal>\dD+</literal></entry>
</row>
<row>
<entry><literal>FUNCTION</literal> or <literal>PROCEDURE</literal></entry>
<entry><literal>X</literal></entry>
<entry><literal>X</literal></entry>
<entry><literal>\df+</literal></entry>
</row>
<row>
<entry><literal>FOREIGN DATA WRAPPER</literal></entry>
<entry><literal>U</literal></entry>
<entry>none</entry>
<entry><literal>\dew+</literal></entry>
</row>
<row>
<entry><literal>FOREIGN SERVER</literal></entry>
<entry><literal>U</literal></entry>
<entry>none</entry>
<entry><literal>\des+</literal></entry>
</row>
<row>
<entry><literal>LANGUAGE</literal></entry>
<entry><literal>U</literal></entry>
<entry><literal>U</literal></entry>
<entry><literal>\dL+</literal></entry>
</row>
<row>
<entry><literal>LARGE OBJECT</literal></entry>
<entry><literal>rw</literal></entry>
<entry>none</entry>
<entry></entry>
</row>
<row>
<entry><literal>SCHEMA</literal></entry>
<entry><literal>UC</literal></entry>
<entry>none</entry>
<entry><literal>\dn+</literal></entry>
</row>
<row>
<entry><literal>SEQUENCE</literal></entry>
<entry><literal>rwU</literal></entry>
<entry>none</entry>
<entry><literal>\dp</literal></entry>
</row>
<row>
<entry><literal>TABLE</literal> (and table-like objects)</entry>
<entry><literal>arwdDxt</literal></entry>
<entry>none</entry>
<entry><literal>\dp</literal></entry>
</row>
<row>
<entry>Table column</entry>
<entry><literal>arwx</literal></entry>
<entry>none</entry>
<entry><literal>\dp</literal></entry>
</row>
<row>
<entry><literal>TABLESPACE</literal></entry>
<entry><literal>C</literal></entry>
<entry>none</entry>
<entry><literal>\db+</literal></entry>
</row>
<row>
<entry><literal>TYPE</literal></entry>
<entry><literal>U</literal></entry>
<entry><literal>U</literal></entry>
<entry><literal>\dT+</literal></entry>
</row>
</tbody>
</tgroup>
</table>
<para>
<indexterm>
<primary><type>aclitem</type></primary>
</indexterm>
The privileges that have been granted for a particular object are
displayed as a list of <type>aclitem</type> entries, where each
<type>aclitem</type> describes the permissions of one grantee that
have been granted by a particular grantor. For example,
<literal>calvin=r*w/hobbes</literal> specifies that the role
<literal>calvin</literal> has the privilege
<literal>SELECT</literal> (<literal>r</literal>) with grant option
(<literal>*</literal>) as well as the non-grantable
privilege <literal>UPDATE</literal> (<literal>w</literal>), both granted
by the role <literal>hobbes</literal>. If <literal>calvin</literal>
also has some privileges on the same object granted by a different
grantor, those would appear as a separate <type>aclitem</type> entry.
An empty grantee field in an <type>aclitem</type> stands
for <literal>PUBLIC</literal>.
</para>
<para>
As an example, suppose that user <literal>miriam</literal> creates
table <literal>mytable</literal> and does:
<programlisting>
GRANT SELECT ON mytable TO PUBLIC;
GRANT SELECT, UPDATE, INSERT ON mytable TO admin;
GRANT SELECT (col1), UPDATE (col1) ON mytable TO miriam_rw;
</programlisting>
Then <application>psql</application>'s <literal>\dp</literal> command
would show:
<programlisting>
=> \dp mytable
Access privileges
Schema | Name | Type | Access privileges | Column privileges | Policies
--------+---------+-------+-----------------------+-----------------------+----------
public | mytable | table | miriam=arwdDxt/miriam+| col1: +|
| | | =r/miriam +| miriam_rw=rw/miriam |
| | | admin=arw/miriam | |
(1 row)
</programlisting>
</para>
<para>
If the <quote>Access privileges</quote> column is empty for a given
object, it means the object has default privileges (that is, its
privileges entry in the relevant system catalog is null). Default
privileges always include all privileges for the owner, and can include
some privileges for <literal>PUBLIC</literal> depending on the object
type, as explained above. The first <command>GRANT</command>
or <command>REVOKE</command> on an object will instantiate the default
privileges (producing, for
example, <literal>miriam=arwdDxt/miriam</literal>) and then modify them
per the specified request. Similarly, entries are shown in <quote>Column
privileges</quote> only for columns with nondefault privileges.
(Note: for this purpose, <quote>default privileges</quote> always means
the built-in default privileges for the object's type. An object whose
privileges have been affected by an <command>ALTER DEFAULT
PRIVILEGES</command> command will always be shown with an explicit
privilege entry that includes the effects of
the <command>ALTER</command>.)
</para>
<para>
Notice that the owner's implicit grant options are not marked in the
access privileges display. A <literal>*</literal> will appear only when
grant options have been explicitly granted to someone.
</para>
</sect1>
<sect1 id="ddl-rowsecurity">
<title>Row Security Policies</title>
<indexterm zone="ddl-rowsecurity">
<primary>row-level security</primary>
</indexterm>
<indexterm zone="ddl-rowsecurity">
<primary>policy</primary>
</indexterm>
<para>
In addition to the SQL-standard <link linkend="ddl-priv">privilege
system</link> available through <xref linkend="sql-grant"/>,
tables can have <firstterm>row security policies</firstterm> that restrict,
on a per-user basis, which rows can be returned by normal queries
or inserted, updated, or deleted by data modification commands.
This feature is also known as <firstterm>Row-Level Security</firstterm>.
By default, tables do not have any policies, so that if a user has
access privileges to a table according to the SQL privilege system,
all rows within it are equally available for querying or updating.
</para>
<para>
When row security is enabled on a table (with
<link linkend="sql-altertable">ALTER TABLE ... ENABLE ROW LEVEL
SECURITY</link>), all normal access to the table for selecting rows or
modifying rows must be allowed by a row security policy. (However, the
table's owner is typically not subject to row security policies.) If no
policy exists for the table, a default-deny policy is used, meaning that
no rows are visible or can be modified. Operations that apply to the
whole table, such as <command>TRUNCATE</command> and <literal>REFERENCES</literal>,
are not subject to row security.
</para>
<para>
Row security policies can be specific to commands, or to roles, or to
both. A policy can be specified to apply to <literal>ALL</literal>
commands, or to <literal>SELECT</literal>, <literal>INSERT</literal>, <literal>UPDATE</literal>,
or <literal>DELETE</literal>. Multiple roles can be assigned to a given
policy, and normal role membership and inheritance rules apply.
</para>
<para>
To specify which rows are visible or modifiable according to a policy,
an expression is required that returns a Boolean result. This
expression will be evaluated for each row prior to any conditions or
functions coming from the user's query. (The only exceptions to this
rule are <literal>leakproof</literal> functions, which are guaranteed to
not leak information; the optimizer may choose to apply such functions
ahead of the row-security check.) Rows for which the expression does
not return <literal>true</literal> will not be processed. Separate expressions
may be specified to provide independent control over the rows which are
visible and the rows which are allowed to be modified. Policy
expressions are run as part of the query and with the privileges of the
user running the query, although security-definer functions can be used
to access data not available to the calling user.
</para>
<para>
Superusers and roles with the <literal>BYPASSRLS</literal> attribute always
bypass the row security system when accessing a table. Table owners
normally bypass row security as well, though a table owner can choose to
be subject to row security with <link linkend="sql-altertable">ALTER
TABLE ... FORCE ROW LEVEL SECURITY</link>.
</para>
<para>
Enabling and disabling row security, as well as adding policies to a
table, is always the privilege of the table owner only.
</para>
<para>
Policies are created using the <xref linkend="sql-createpolicy"/>
command, altered using the <xref linkend="sql-alterpolicy"/> command,
and dropped using the <xref linkend="sql-droppolicy"/> command. To
enable and disable row security for a given table, use the
<xref linkend="sql-altertable"/> command.
</para>
<para>
Each policy has a name and multiple policies can be defined for a
table. As policies are table-specific, each policy for a table must
have a unique name. Different tables may have policies with the
same name.
</para>
<para>
When multiple policies apply to a given query, they are combined using
either <literal>OR</literal> (for permissive policies, which are the
default) or using <literal>AND</literal> (for restrictive policies).
This is similar to the rule that a given role has the privileges
of all roles that they are a member of. Permissive vs. restrictive
policies are discussed further below.
</para>
<para>
As a simple example, here is how to create a policy on
the <literal>account</literal> relation to allow only members of
the <literal>managers</literal> role to access rows, and only rows of their
accounts:
</para>
<programlisting>
CREATE TABLE accounts (manager text, company text, contact_email text);
ALTER TABLE accounts ENABLE ROW LEVEL SECURITY;
CREATE POLICY account_managers ON accounts TO managers
USING (manager = current_user);
</programlisting>
<para>
The policy above implicitly provides a <literal>WITH CHECK</literal>
clause identical to its <literal>USING</literal> clause, so that the
constraint applies both to rows selected by a command (so a manager
cannot <command>SELECT</command>, <command>UPDATE</command>,
or <command>DELETE</command> existing rows belonging to a different
manager) and to rows modified by a command (so rows belonging to a
different manager cannot be created via <command>INSERT</command>
or <command>UPDATE</command>).
</para>
<para>
If no role is specified, or the special user name
<literal>PUBLIC</literal> is used, then the policy applies to all
users on the system. To allow all users to access only their own row in
a <literal>users</literal> table, a simple policy can be used:
</para>
<programlisting>
CREATE POLICY user_policy ON users
USING (user_name = current_user);
</programlisting>
<para>
This works similarly to the previous example.
</para>
<para>
To use a different policy for rows that are being added to the table
compared to those rows that are visible, multiple policies can be
combined. This pair of policies would allow all users to view all rows
in the <literal>users</literal> table, but only modify their own:
</para>
<programlisting>
CREATE POLICY user_sel_policy ON users
FOR SELECT
USING (true);
CREATE POLICY user_mod_policy ON users
USING (user_name = current_user);
</programlisting>
<para>
In a <command>SELECT</command> command, these two policies are combined
using <literal>OR</literal>, with the net effect being that all rows
can be selected. In other command types, only the second policy applies,
so that the effects are the same as before.
</para>
<para>
Row security can also be disabled with the <command>ALTER TABLE</command>
command. Disabling row security does not remove any policies that are
defined on the table; they are simply ignored. Then all rows in the
table are visible and modifiable, subject to the standard SQL privileges
system.
</para>
<para>
Below is a larger example of how this feature can be used in production
environments. The table <literal>passwd</literal> emulates a Unix password
file:
</para>
<programlisting>
-- Simple passwd-file based example
CREATE TABLE passwd (
user_name text UNIQUE NOT NULL,
pwhash text,
uid int PRIMARY KEY,
gid int NOT NULL,
real_name text NOT NULL,
home_phone text,
extra_info text,
home_dir text NOT NULL,
shell text NOT NULL
);
CREATE ROLE admin; -- Administrator
CREATE ROLE bob; -- Normal user
CREATE ROLE alice; -- Normal user
-- Populate the table
INSERT INTO passwd VALUES
('admin','xxx',0,0,'Admin','111-222-3333',null,'/root','/bin/dash');
INSERT INTO passwd VALUES
('bob','xxx',1,1,'Bob','123-456-7890',null,'/home/bob','/bin/zsh');
INSERT INTO passwd VALUES
('alice','xxx',2,1,'Alice','098-765-4321',null,'/home/alice','/bin/zsh');
-- Be sure to enable row-level security on the table
ALTER TABLE passwd ENABLE ROW LEVEL SECURITY;
-- Create policies
-- Administrator can see all rows and add any rows
CREATE POLICY admin_all ON passwd TO admin USING (true) WITH CHECK (true);
-- Normal users can view all rows
CREATE POLICY all_view ON passwd FOR SELECT USING (true);
-- Normal users can update their own records, but
-- limit which shells a normal user is allowed to set
CREATE POLICY user_mod ON passwd FOR UPDATE
USING (current_user = user_name)
WITH CHECK (
current_user = user_name AND
shell IN ('/bin/bash','/bin/sh','/bin/dash','/bin/zsh','/bin/tcsh')
);
-- Allow admin all normal rights
GRANT SELECT, INSERT, UPDATE, DELETE ON passwd TO admin;
-- Users only get select access on public columns
GRANT SELECT
(user_name, uid, gid, real_name, home_phone, extra_info, home_dir, shell)
ON passwd TO public;
-- Allow users to update certain columns
GRANT UPDATE
(pwhash, real_name, home_phone, extra_info, shell)
ON passwd TO public;
</programlisting>
<para>
As with any security settings, it's important to test and ensure that
the system is behaving as expected. Using the example above, this
demonstrates that the permission system is working properly.
</para>
<programlisting>
-- admin can view all rows and fields
postgres=> set role admin;
SET
postgres=> table passwd;
user_name | pwhash | uid | gid | real_name | home_phone | extra_info | home_dir | shell
-----------+--------+-----+-----+-----------+--------------+------------+-------------+-----------
admin | xxx | 0 | 0 | Admin | 111-222-3333 | | /root | /bin/dash
bob | xxx | 1 | 1 | Bob | 123-456-7890 | | /home/bob | /bin/zsh
alice | xxx | 2 | 1 | Alice | 098-765-4321 | | /home/alice | /bin/zsh
(3 rows)
-- Test what Alice is able to do
postgres=> set role alice;
SET
postgres=> table passwd;
ERROR: permission denied for relation passwd
postgres=> select user_name,real_name,home_phone,extra_info,home_dir,shell from passwd;
user_name | real_name | home_phone | extra_info | home_dir | shell
-----------+-----------+--------------+------------+-------------+-----------
admin | Admin | 111-222-3333 | | /root | /bin/dash
bob | Bob | 123-456-7890 | | /home/bob | /bin/zsh
alice | Alice | 098-765-4321 | | /home/alice | /bin/zsh
(3 rows)
postgres=> update passwd set user_name = 'joe';
ERROR: permission denied for relation passwd
-- Alice is allowed to change her own real_name, but no others
postgres=> update passwd set real_name = 'Alice Doe';
UPDATE 1
postgres=> update passwd set real_name = 'John Doe' where user_name = 'admin';
UPDATE 0
postgres=> update passwd set shell = '/bin/xx';
ERROR: new row violates WITH CHECK OPTION for "passwd"
postgres=> delete from passwd;
ERROR: permission denied for relation passwd
postgres=> insert into passwd (user_name) values ('xxx');
ERROR: permission denied for relation passwd
-- Alice can change her own password; RLS silently prevents updating other rows
postgres=> update passwd set pwhash = 'abc';
UPDATE 1
</programlisting>
<para>
All of the policies constructed thus far have been permissive policies,
meaning that when multiple policies are applied they are combined using
the <quote>OR</quote> Boolean operator. While permissive policies can be constructed
to only allow access to rows in the intended cases, it can be simpler to
combine permissive policies with restrictive policies (which the records
must pass and which are combined using the <quote>AND</quote> Boolean operator).
Building on the example above, we add a restrictive policy to require
the administrator to be connected over a local Unix socket to access the
records of the <literal>passwd</literal> table:
</para>
<programlisting>
CREATE POLICY admin_local_only ON passwd AS RESTRICTIVE TO admin
USING (pg_catalog.inet_client_addr() IS NULL);
</programlisting>
<para>
We can then see that an administrator connecting over a network will not
see any records, due to the restrictive policy:
</para>
<programlisting>
=> SELECT current_user;
current_user
--------------
admin
(1 row)
=> select inet_client_addr();
inet_client_addr
------------------
127.0.0.1
(1 row)
=> TABLE passwd;
user_name | pwhash | uid | gid | real_name | home_phone | extra_info | home_dir | shell
-----------+--------+-----+-----+-----------+------------+------------+----------+-------
(0 rows)
=> UPDATE passwd set pwhash = NULL;
UPDATE 0
</programlisting>
<para>
Referential integrity checks, such as unique or primary key constraints
and foreign key references, always bypass row security to ensure that
data integrity is maintained. Care must be taken when developing
schemas and row level policies to avoid <quote>covert channel</quote> leaks of
information through such referential integrity checks.
</para>
<para>
In some contexts it is important to be sure that row security is
not being applied. For example, when taking a backup, it could be
disastrous if row security silently caused some rows to be omitted
from the backup. In such a situation, you can set the
<xref linkend="guc-row-security"/> configuration parameter
to <literal>off</literal>. This does not in itself bypass row security;
what it does is throw an error if any query's results would get filtered
by a policy. The reason for the error can then be investigated and
fixed.
</para>
<para>
In the examples above, the policy expressions consider only the current
values in the row to be accessed or updated. This is the simplest and
best-performing case; when possible, it's best to design row security
applications to work this way. If it is necessary to consult other rows
or other tables to make a policy decision, that can be accomplished using
sub-<command>SELECT</command>s, or functions that contain <command>SELECT</command>s,
in the policy expressions. Be aware however that such accesses can
create race conditions that could allow information leakage if care is
not taken. As an example, consider the following table design:
</para>
<programlisting>
-- definition of privilege groups
CREATE TABLE groups (group_id int PRIMARY KEY,
group_name text NOT NULL);
INSERT INTO groups VALUES
(1, 'low'),
(2, 'medium'),
(5, 'high');
GRANT ALL ON groups TO alice; -- alice is the administrator
GRANT SELECT ON groups TO public;
-- definition of users' privilege levels
CREATE TABLE users (user_name text PRIMARY KEY,
group_id int NOT NULL REFERENCES groups);
INSERT INTO users VALUES
('alice', 5),
('bob', 2),
('mallory', 2);
GRANT ALL ON users TO alice;
GRANT SELECT ON users TO public;
-- table holding the information to be protected
CREATE TABLE information (info text,
group_id int NOT NULL REFERENCES groups);
INSERT INTO information VALUES
('barely secret', 1),
('slightly secret', 2),
('very secret', 5);
ALTER TABLE information ENABLE ROW LEVEL SECURITY;
-- a row should be visible to/updatable by users whose security group_id is
-- greater than or equal to the row's group_id
CREATE POLICY fp_s ON information FOR SELECT
USING (group_id <= (SELECT group_id FROM users WHERE user_name = current_user));
CREATE POLICY fp_u ON information FOR UPDATE
USING (group_id <= (SELECT group_id FROM users WHERE user_name = current_user));
-- we rely only on RLS to protect the information table
GRANT ALL ON information TO public;
</programlisting>
<para>
Now suppose that <literal>alice</literal> wishes to change the <quote>slightly
secret</quote> information, but decides that <literal>mallory</literal> should not
be trusted with the new content of that row, so she does:
</para>
<programlisting>
BEGIN;
UPDATE users SET group_id = 1 WHERE user_name = 'mallory';
UPDATE information SET info = 'secret from mallory' WHERE group_id = 2;
COMMIT;
</programlisting>
<para>
That looks safe; there is no window wherein <literal>mallory</literal> should be
able to see the <quote>secret from mallory</quote> string. However, there is
a race condition here. If <literal>mallory</literal> is concurrently doing,
say,
<programlisting>
SELECT * FROM information WHERE group_id = 2 FOR UPDATE;
</programlisting>
and her transaction is in <literal>READ COMMITTED</literal> mode, it is possible
for her to see <quote>secret from mallory</quote>. That happens if her
transaction reaches the <structname>information</structname> row just
after <literal>alice</literal>'s does. It blocks waiting
for <literal>alice</literal>'s transaction to commit, then fetches the updated
row contents thanks to the <literal>FOR UPDATE</literal> clause. However, it
does <emphasis>not</emphasis> fetch an updated row for the
implicit <command>SELECT</command> from <structname>users</structname>, because that
sub-<command>SELECT</command> did not have <literal>FOR UPDATE</literal>; instead
the <structname>users</structname> row is read with the snapshot taken at the start
of the query. Therefore, the policy expression tests the old value
of <literal>mallory</literal>'s privilege level and allows her to see the
updated row.
</para>
<para>
There are several ways around this problem. One simple answer is to use
<literal>SELECT ... FOR SHARE</literal> in sub-<command>SELECT</command>s in row
security policies. However, that requires granting <literal>UPDATE</literal>
privilege on the referenced table (here <structname>users</structname>) to the
affected users, which might be undesirable. (But another row security
policy could be applied to prevent them from actually exercising that
privilege; or the sub-<command>SELECT</command> could be embedded into a security
definer function.) Also, heavy concurrent use of row share locks on the
referenced table could pose a performance problem, especially if updates
of it are frequent. Another solution, practical if updates of the
referenced table are infrequent, is to take an
<literal>ACCESS EXCLUSIVE</literal> lock on the
referenced table when updating it, so that no concurrent transactions
could be examining old row values. Or one could just wait for all
concurrent transactions to end after committing an update of the
referenced table and before making changes that rely on the new security
situation.
</para>
<para>
For additional details see <xref linkend="sql-createpolicy"/>
and <xref linkend="sql-altertable"/>.
</para>
</sect1>
<sect1 id="ddl-schemas">
<title>Schemas</title>
<indexterm zone="ddl-schemas">
<primary>schema</primary>
</indexterm>
<para>
A <productname>PostgreSQL</productname> database cluster contains
one or more named databases. Roles and a few other object types are
shared across the entire cluster. A client connection to the server
can only access data in a single database, the one specified in the
connection request.
</para>
<note>
<para>
Users of a cluster do not necessarily have the privilege to access every
database in the cluster. Sharing of role names means that there
cannot be different roles named, say, <literal>joe</literal> in two databases
in the same cluster; but the system can be configured to allow
<literal>joe</literal> access to only some of the databases.
</para>
</note>
<para>
A database contains one or more named <firstterm>schemas</firstterm>, which
in turn contain tables. Schemas also contain other kinds of named
objects, including data types, functions, and operators. The same
object name can be used in different schemas without conflict; for
example, both <literal>schema1</literal> and <literal>myschema</literal> can
contain tables named <literal>mytable</literal>. Unlike databases,
schemas are not rigidly separated: a user can access objects in any
of the schemas in the database they are connected to, if they have
privileges to do so.
</para>
<para>
There are several reasons why one might want to use schemas:
<itemizedlist>
<listitem>
<para>
To allow many users to use one database without interfering with
each other.
</para>
</listitem>
<listitem>
<para>
To organize database objects into logical groups to make them
more manageable.
</para>
</listitem>
<listitem>
<para>
Third-party applications can be put into separate schemas so
they do not collide with the names of other objects.
</para>
</listitem>
</itemizedlist>
Schemas are analogous to directories at the operating system level,
except that schemas cannot be nested.
</para>
<sect2 id="ddl-schemas-create">
<title>Creating a Schema</title>
<indexterm zone="ddl-schemas-create">
<primary>schema</primary>
<secondary>creating</secondary>
</indexterm>
<para>
To create a schema, use the <xref linkend="sql-createschema"/>
command. Give the schema a name
of your choice. For example:
<programlisting>
CREATE SCHEMA myschema;
</programlisting>
</para>
<indexterm>
<primary>qualified name</primary>
</indexterm>
<indexterm>
<primary>name</primary>
<secondary>qualified</secondary>
</indexterm>
<para>
To create or access objects in a schema, write a
<firstterm>qualified name</firstterm> consisting of the schema name and
table name separated by a dot:
<synopsis>
<replaceable>schema</replaceable><literal>.</literal><replaceable>table</replaceable>
</synopsis>
This works anywhere a table name is expected, including the table
modification commands and the data access commands discussed in
the following chapters.
(For brevity we will speak of tables only, but the same ideas apply
to other kinds of named objects, such as types and functions.)
</para>
<para>
Actually, the even more general syntax
<synopsis>
<replaceable>database</replaceable><literal>.</literal><replaceable>schema</replaceable><literal>.</literal><replaceable>table</replaceable>
</synopsis>
can be used too, but at present this is just for pro forma
compliance with the SQL standard. If you write a database name,
it must be the same as the database you are connected to.
</para>
<para>
So to create a table in the new schema, use:
<programlisting>
CREATE TABLE myschema.mytable (
...
);
</programlisting>
</para>
<indexterm>
<primary>schema</primary>
<secondary>removing</secondary>
</indexterm>
<para>
To drop a schema if it's empty (all objects in it have been
dropped), use:
<programlisting>
DROP SCHEMA myschema;
</programlisting>
To drop a schema including all contained objects, use:
<programlisting>
DROP SCHEMA myschema CASCADE;
</programlisting>
See <xref linkend="ddl-depend"/> for a description of the general
mechanism behind this.
</para>
<para>
Often you will want to create a schema owned by someone else
(since this is one of the ways to restrict the activities of your
users to well-defined namespaces). The syntax for that is:
<programlisting>
CREATE SCHEMA <replaceable>schema_name</replaceable> AUTHORIZATION <replaceable>user_name</replaceable>;
</programlisting>
You can even omit the schema name, in which case the schema name
will be the same as the user name. See <xref
linkend="ddl-schemas-patterns"/> for how this can be useful.
</para>
<para>
Schema names beginning with <literal>pg_</literal> are reserved for
system purposes and cannot be created by users.
</para>
</sect2>
<sect2 id="ddl-schemas-public">
<title>The Public Schema</title>
<indexterm zone="ddl-schemas-public">
<primary>schema</primary>
<secondary>public</secondary>
</indexterm>
<para>
In the previous sections we created tables without specifying any
schema names. By default such tables (and other objects) are
automatically put into a schema named <quote>public</quote>. Every new
database contains such a schema. Thus, the following are equivalent:
<programlisting>
CREATE TABLE products ( ... );
</programlisting>
and:
<programlisting>
CREATE TABLE public.products ( ... );
</programlisting>
</para>
</sect2>
<sect2 id="ddl-schemas-path">
<title>The Schema Search Path</title>
<indexterm>
<primary>search path</primary>
</indexterm>
<indexterm>
<primary>unqualified name</primary>
</indexterm>
<indexterm>
<primary>name</primary>
<secondary>unqualified</secondary>
</indexterm>
<para>
Qualified names are tedious to write, and it's often best not to
wire a particular schema name into applications anyway. Therefore
tables are often referred to by <firstterm>unqualified names</firstterm>,
which consist of just the table name. The system determines which table
is meant by following a <firstterm>search path</firstterm>, which is a list
of schemas to look in. The first matching table in the search path
is taken to be the one wanted. If there is no match in the search
path, an error is reported, even if matching table names exist
in other schemas in the database.
</para>
<para>
The ability to create like-named objects in different schemas complicates
writing a query that references precisely the same objects every time. It
also opens up the potential for users to change the behavior of other
users' queries, maliciously or accidentally. Due to the prevalence of
unqualified names in queries and their use
in <productname>PostgreSQL</productname> internals, adding a schema
to <varname>search_path</varname> effectively trusts all users having
<literal>CREATE</literal> privilege on that schema. When you run an
ordinary query, a malicious user able to create objects in a schema of
your search path can take control and execute arbitrary SQL functions as
though you executed them.
</para>
<indexterm>
<primary>schema</primary>
<secondary>current</secondary>
</indexterm>
<para>
The first schema named in the search path is called the current schema.
Aside from being the first schema searched, it is also the schema in
which new tables will be created if the <command>CREATE TABLE</command>
command does not specify a schema name.
</para>
<indexterm>
<primary><varname>search_path</varname> configuration parameter</primary>
</indexterm>
<para>
To show the current search path, use the following command:
<programlisting>
SHOW search_path;
</programlisting>
In the default setup this returns:
<screen>
search_path
--------------
"$user", public
</screen>
The first element specifies that a schema with the same name as
the current user is to be searched. If no such schema exists,
the entry is ignored. The second element refers to the
public schema that we have seen already.
</para>
<para>
The first schema in the search path that exists is the default
location for creating new objects. That is the reason that by
default objects are created in the public schema. When objects
are referenced in any other context without schema qualification
(table modification, data modification, or query commands) the
search path is traversed until a matching object is found.
Therefore, in the default configuration, any unqualified access
again can only refer to the public schema.
</para>
<para>
To put our new schema in the path, we use:
<programlisting>
SET search_path TO myschema,public;
</programlisting>
(We omit the <literal>$user</literal> here because we have no
immediate need for it.) And then we can access the table without
schema qualification:
<programlisting>
DROP TABLE mytable;
</programlisting>
Also, since <literal>myschema</literal> is the first element in
the path, new objects would by default be created in it.
</para>
<para>
We could also have written:
<programlisting>
SET search_path TO myschema;
</programlisting>
Then we no longer have access to the public schema without
explicit qualification. There is nothing special about the public
schema except that it exists by default. It can be dropped, too.
</para>
<para>
See also <xref linkend="functions-info"/> for other ways to manipulate
the schema search path.
</para>
<para>
The search path works in the same way for data type names, function names,
and operator names as it does for table names. Data type and function
names can be qualified in exactly the same way as table names. If you
need to write a qualified operator name in an expression, there is a
special provision: you must write
<synopsis>
<literal>OPERATOR(</literal><replaceable>schema</replaceable><literal>.</literal><replaceable>operator</replaceable><literal>)</literal>
</synopsis>
This is needed to avoid syntactic ambiguity. An example is:
<programlisting>
SELECT 3 OPERATOR(pg_catalog.+) 4;
</programlisting>
In practice one usually relies on the search path for operators,
so as not to have to write anything so ugly as that.
</para>
</sect2>
<sect2 id="ddl-schemas-priv">
<title>Schemas and Privileges</title>
<indexterm zone="ddl-schemas-priv">
<primary>privilege</primary>
<secondary sortas="schemas">for schemas</secondary>
</indexterm>
<para>
By default, users cannot access any objects in schemas they do not
own. To allow that, the owner of the schema must grant the
<literal>USAGE</literal> privilege on the schema. To allow users
to make use of the objects in the schema, additional privileges
might need to be granted, as appropriate for the object.
</para>
<para>
A user can also be allowed to create objects in someone else's
schema. To allow that, the <literal>CREATE</literal> privilege on
the schema needs to be granted. Note that by default, everyone
has <literal>CREATE</literal> and <literal>USAGE</literal> privileges on
the schema
<literal>public</literal>. This allows all users that are able to
connect to a given database to create objects in its
<literal>public</literal> schema.
Some <link linkend="ddl-schemas-patterns">usage patterns</link> call for
revoking that privilege:
<programlisting>
REVOKE CREATE ON SCHEMA public FROM PUBLIC;
</programlisting>
(The first <quote>public</quote> is the schema, the second
<quote>public</quote> means <quote>every user</quote>. In the
first sense it is an identifier, in the second sense it is a
key word, hence the different capitalization; recall the
guidelines from <xref linkend="sql-syntax-identifiers"/>.)
</para>
</sect2>
<sect2 id="ddl-schemas-catalog">
<title>The System Catalog Schema</title>
<indexterm zone="ddl-schemas-catalog">
<primary>system catalog</primary>
<secondary>schema</secondary>
</indexterm>
<para>
In addition to <literal>public</literal> and user-created schemas, each
database contains a <literal>pg_catalog</literal> schema, which contains
the system tables and all the built-in data types, functions, and
operators. <literal>pg_catalog</literal> is always effectively part of
the search path. If it is not named explicitly in the path then
it is implicitly searched <emphasis>before</emphasis> searching the path's
schemas. This ensures that built-in names will always be
findable. However, you can explicitly place
<literal>pg_catalog</literal> at the end of your search path if you
prefer to have user-defined names override built-in names.
</para>
<para>
Since system table names begin with <literal>pg_</literal>, it is best to
avoid such names to ensure that you won't suffer a conflict if some
future version defines a system table named the same as your
table. (With the default search path, an unqualified reference to
your table name would then be resolved as the system table instead.)
System tables will continue to follow the convention of having
names beginning with <literal>pg_</literal>, so that they will not
conflict with unqualified user-table names so long as users avoid
the <literal>pg_</literal> prefix.
</para>
</sect2>
<sect2 id="ddl-schemas-patterns">
<title>Usage Patterns</title>
<para>
Schemas can be used to organize your data in many ways.
A <firstterm>secure schema usage pattern</firstterm> prevents untrusted
users from changing the behavior of other users' queries. When a database
does not use a secure schema usage pattern, users wishing to securely
query that database would take protective action at the beginning of each
session. Specifically, they would begin each session by
setting <varname>search_path</varname> to the empty string or otherwise
removing non-superuser-writable schemas
from <varname>search_path</varname>. There are a few usage patterns
easily supported by the default configuration:
<itemizedlist>
<listitem>
<!-- "DROP SCHEMA public" is inferior to this REVOKE, because pg_dump
doesn't preserve that DROP.
A database owner can attack the database's users via "CREATE SCHEMA
trojan; ALTER DATABASE $mydb SET search_path = trojan, public;". A
CREATEROLE user can issue "GRANT $dbowner TO $me" and then use the
database owner attack. -->
<para>
Constrain ordinary users to user-private schemas. To implement this,
issue <literal>REVOKE CREATE ON SCHEMA public FROM PUBLIC</literal>,
and create a schema for each user with the same name as that user.
Recall that the default search path starts
with <literal>$user</literal>, which resolves to the user name.
Therefore, if each user has a separate schema, they access their own
schemas by default. After adopting this pattern in a database where
untrusted users had already logged in, consider auditing the public
schema for objects named like objects in
schema <literal>pg_catalog</literal>. This pattern is a secure schema
usage pattern unless an untrusted user is the database owner or holds
the <literal>CREATEROLE</literal> privilege, in which case no secure
schema usage pattern exists.
</para>
<para>
</para>
</listitem>
<listitem>
<para>
Remove the public schema from the default search path, by modifying
<link linkend="config-setting-configuration-file"><filename>postgresql.conf</filename></link>
or by issuing <literal>ALTER ROLE ALL SET search_path =
"$user"</literal>. Everyone retains the ability to create objects in
the public schema, but only qualified names will choose those objects.
While qualified table references are fine, calls to functions in the
public schema <link linkend="typeconv-func">will be unsafe or
unreliable</link>. If you create functions or extensions in the public
schema, use the first pattern instead. Otherwise, like the first
pattern, this is secure unless an untrusted user is the database owner
or holds the <literal>CREATEROLE</literal> privilege.
</para>
</listitem>
<listitem>
<para>
Keep the default. All users access the public schema implicitly. This
simulates the situation where schemas are not available at all, giving
a smooth transition from the non-schema-aware world. However, this is
never a secure pattern. It is acceptable only when the database has a
single user or a few mutually-trusting users.
</para>
</listitem>
</itemizedlist>
</para>
<para>
For any pattern, to install shared applications (tables to be used by
everyone, additional functions provided by third parties, etc.), put them
into separate schemas. Remember to grant appropriate privileges to allow
the other users to access them. Users can then refer to these additional
objects by qualifying the names with a schema name, or they can put the
additional schemas into their search path, as they choose.
</para>
</sect2>
<sect2 id="ddl-schemas-portability">
<title>Portability</title>
<para>
In the SQL standard, the notion of objects in the same schema
being owned by different users does not exist. Moreover, some
implementations do not allow you to create schemas that have a
different name than their owner. In fact, the concepts of schema
and user are nearly equivalent in a database system that
implements only the basic schema support specified in the
standard. Therefore, many users consider qualified names to
really consist of
<literal><replaceable>user_name</replaceable>.<replaceable>table_name</replaceable></literal>.
This is how <productname>PostgreSQL</productname> will effectively
behave if you create a per-user schema for every user.
</para>
<para>
Also, there is no concept of a <literal>public</literal> schema in the
SQL standard. For maximum conformance to the standard, you should
not use the <literal>public</literal> schema.
</para>
<para>
Of course, some SQL database systems might not implement schemas
at all, or provide namespace support by allowing (possibly
limited) cross-database access. If you need to work with those
systems, then maximum portability would be achieved by not using
schemas at all.
</para>
</sect2>
</sect1>
<sect1 id="ddl-inherit">
<title>Inheritance</title>
<indexterm>
<primary>inheritance</primary>
</indexterm>
<indexterm>
<primary>table</primary>
<secondary>inheritance</secondary>
</indexterm>
<para>
<productname>PostgreSQL</productname> implements table inheritance,
which can be a useful tool for database designers. (SQL:1999 and
later define a type inheritance feature, which differs in many
respects from the features described here.)
</para>
<para>
Let's start with an example: suppose we are trying to build a data
model for cities. Each state has many cities, but only one
capital. We want to be able to quickly retrieve the capital city
for any particular state. This can be done by creating two tables,
one for state capitals and one for cities that are not
capitals. However, what happens when we want to ask for data about
a city, regardless of whether it is a capital or not? The
inheritance feature can help to resolve this problem. We define the
<structname>capitals</structname> table so that it inherits from
<structname>cities</structname>:
<programlisting>
CREATE TABLE cities (
name text,
population float,
elevation int -- in feet
);
CREATE TABLE capitals (
state char(2)
) INHERITS (cities);
</programlisting>
In this case, the <structname>capitals</structname> table <firstterm>inherits</firstterm>
all the columns of its parent table, <structname>cities</structname>. State
capitals also have an extra column, <structfield>state</structfield>, that shows
their state.
</para>
<para>
In <productname>PostgreSQL</productname>, a table can inherit from
zero or more other tables, and a query can reference either all
rows of a table or all rows of a table plus all of its descendant tables.
The latter behavior is the default.
For example, the following query finds the names of all cities,
including state capitals, that are located at an elevation over
500 feet:
<programlisting>
SELECT name, elevation
FROM cities
WHERE elevation > 500;
</programlisting>
Given the sample data from the <productname>PostgreSQL</productname>
tutorial (see <xref linkend="tutorial-sql-intro"/>), this returns:
<programlisting>
name | elevation
-----------+-----------
Las Vegas | 2174
Mariposa | 1953
Madison | 845
</programlisting>
</para>
<para>
On the other hand, the following query finds all the cities that
are not state capitals and are situated at an elevation over 500 feet:
<programlisting>
SELECT name, elevation
FROM ONLY cities
WHERE elevation > 500;
name | elevation
-----------+-----------
Las Vegas | 2174
Mariposa | 1953
</programlisting>
</para>
<para>
Here the <literal>ONLY</literal> keyword indicates that the query
should apply only to <structname>cities</structname>, and not any tables
below <structname>cities</structname> in the inheritance hierarchy. Many
of the commands that we have already discussed —
<command>SELECT</command>, <command>UPDATE</command> and
<command>DELETE</command> — support the
<literal>ONLY</literal> keyword.
</para>
<para>
You can also write the table name with a trailing <literal>*</literal>
to explicitly specify that descendant tables are included:
<programlisting>
SELECT name, elevation
FROM cities*
WHERE elevation > 500;
</programlisting>
Writing <literal>*</literal> is not necessary, since this behavior is always
the default. However, this syntax is still supported for
compatibility with older releases where the default could be changed.
</para>
<para>
In some cases you might wish to know which table a particular row
originated from. There is a system column called
<structfield>tableoid</structfield> in each table which can tell you the
originating table:
<programlisting>
SELECT c.tableoid, c.name, c.elevation
FROM cities c
WHERE c.elevation > 500;
</programlisting>
which returns:
<programlisting>
tableoid | name | elevation
----------+-----------+-----------
139793 | Las Vegas | 2174
139793 | Mariposa | 1953
139798 | Madison | 845
</programlisting>
(If you try to reproduce this example, you will probably get
different numeric OIDs.) By doing a join with
<structname>pg_class</structname> you can see the actual table names:
<programlisting>
SELECT p.relname, c.name, c.elevation
FROM cities c, pg_class p
WHERE c.elevation > 500 AND c.tableoid = p.oid;
</programlisting>
which returns:
<programlisting>
relname | name | elevation
----------+-----------+-----------
cities | Las Vegas | 2174
cities | Mariposa | 1953
capitals | Madison | 845
</programlisting>
</para>
<para>
Another way to get the same effect is to use the <type>regclass</type>
alias type, which will print the table OID symbolically:
<programlisting>
SELECT c.tableoid::regclass, c.name, c.elevation
FROM cities c
WHERE c.elevation > 500;
</programlisting>
</para>
<para>
Inheritance does not automatically propagate data from
<command>INSERT</command> or <command>COPY</command> commands to
other tables in the inheritance hierarchy. In our example, the
following <command>INSERT</command> statement will fail:
<programlisting>
INSERT INTO cities (name, population, elevation, state)
VALUES ('Albany', NULL, NULL, 'NY');
</programlisting>
We might hope that the data would somehow be routed to the
<structname>capitals</structname> table, but this does not happen:
<command>INSERT</command> always inserts into exactly the table
specified. In some cases it is possible to redirect the insertion
using a rule (see <xref linkend="rules"/>). However that does not
help for the above case because the <structname>cities</structname> table
does not contain the column <structfield>state</structfield>, and so the
command will be rejected before the rule can be applied.
</para>
<para>
All check constraints and not-null constraints on a parent table are
automatically inherited by its children, unless explicitly specified
otherwise with <literal>NO INHERIT</literal> clauses. Other types of constraints
(unique, primary key, and foreign key constraints) are not inherited.
</para>
<para>
A table can inherit from more than one parent table, in which case it has
the union of the columns defined by the parent tables. Any columns
declared in the child table's definition are added to these. If the
same column name appears in multiple parent tables, or in both a parent
table and the child's definition, then these columns are <quote>merged</quote>
so that there is only one such column in the child table. To be merged,
columns must have the same data types, else an error is raised.
Inheritable check constraints and not-null constraints are merged in a
similar fashion. Thus, for example, a merged column will be marked
not-null if any one of the column definitions it came from is marked
not-null. Check constraints are merged if they have the same name,
and the merge will fail if their conditions are different.
</para>
<para>
Table inheritance is typically established when the child table is
created, using the <literal>INHERITS</literal> clause of the
<link linkend="sql-createtable"><command>CREATE TABLE</command></link>
statement.
Alternatively, a table which is already defined in a compatible way can
have a new parent relationship added, using the <literal>INHERIT</literal>
variant of <link linkend="sql-altertable"><command>ALTER TABLE</command></link>.
To do this the new child table must already include columns with
the same names and types as the columns of the parent. It must also include
check constraints with the same names and check expressions as those of the
parent. Similarly an inheritance link can be removed from a child using the
<literal>NO INHERIT</literal> variant of <command>ALTER TABLE</command>.
Dynamically adding and removing inheritance links like this can be useful
when the inheritance relationship is being used for table
partitioning (see <xref linkend="ddl-partitioning"/>).
</para>
<para>
One convenient way to create a compatible table that will later be made
a new child is to use the <literal>LIKE</literal> clause in <command>CREATE
TABLE</command>. This creates a new table with the same columns as
the source table. If there are any <literal>CHECK</literal>
constraints defined on the source table, the <literal>INCLUDING
CONSTRAINTS</literal> option to <literal>LIKE</literal> should be
specified, as the new child must have constraints matching the parent
to be considered compatible.
</para>
<para>
A parent table cannot be dropped while any of its children remain. Neither
can columns or check constraints of child tables be dropped or altered
if they are inherited
from any parent tables. If you wish to remove a table and all of its
descendants, one easy way is to drop the parent table with the
<literal>CASCADE</literal> option (see <xref linkend="ddl-depend"/>).
</para>
<para>
<command>ALTER TABLE</command> will
propagate any changes in column data definitions and check
constraints down the inheritance hierarchy. Again, dropping
columns that are depended on by other tables is only possible when using
the <literal>CASCADE</literal> option. <command>ALTER
TABLE</command> follows the same rules for duplicate column merging
and rejection that apply during <command>CREATE TABLE</command>.
</para>
<para>
Inherited queries perform access permission checks on the parent table
only. Thus, for example, granting <literal>UPDATE</literal> permission on
the <structname>cities</structname> table implies permission to update rows in
the <structname>capitals</structname> table as well, when they are
accessed through <structname>cities</structname>. This preserves the appearance
that the data is (also) in the parent table. But
the <structname>capitals</structname> table could not be updated directly
without an additional grant. In a similar way, the parent table's row
security policies (see <xref linkend="ddl-rowsecurity"/>) are applied to
rows coming from child tables during an inherited query. A child table's
policies, if any, are applied only when it is the table explicitly named
in the query; and in that case, any policies attached to its parent(s) are
ignored.
</para>
<para>
Foreign tables (see <xref linkend="ddl-foreign-data"/>) can also
be part of inheritance hierarchies, either as parent or child
tables, just as regular tables can be. If a foreign table is part
of an inheritance hierarchy then any operations not supported by
the foreign table are not supported on the whole hierarchy either.
</para>
<sect2 id="ddl-inherit-caveats">
<title>Caveats</title>
<para>
Note that not all SQL commands are able to work on
inheritance hierarchies. Commands that are used for data querying,
data modification, or schema modification
(e.g., <literal>SELECT</literal>, <literal>UPDATE</literal>, <literal>DELETE</literal>,
most variants of <literal>ALTER TABLE</literal>, but
not <literal>INSERT</literal> or <literal>ALTER TABLE ...
RENAME</literal>) typically default to including child tables and
support the <literal>ONLY</literal> notation to exclude them.
Commands that do database maintenance and tuning
(e.g., <literal>REINDEX</literal>, <literal>VACUUM</literal>)
typically only work on individual, physical tables and do not
support recursing over inheritance hierarchies. The respective
behavior of each individual command is documented in its reference
page (<xref linkend="sql-commands"/>).
</para>
<para>
A serious limitation of the inheritance feature is that indexes (including
unique constraints) and foreign key constraints only apply to single
tables, not to their inheritance children. This is true on both the
referencing and referenced sides of a foreign key constraint. Thus,
in the terms of the above example:
<itemizedlist>
<listitem>
<para>
If we declared <structname>cities</structname>.<structfield>name</structfield> to be
<literal>UNIQUE</literal> or a <literal>PRIMARY KEY</literal>, this would not stop the
<structname>capitals</structname> table from having rows with names duplicating
rows in <structname>cities</structname>. And those duplicate rows would by
default show up in queries from <structname>cities</structname>. In fact, by
default <structname>capitals</structname> would have no unique constraint at all,
and so could contain multiple rows with the same name.
You could add a unique constraint to <structname>capitals</structname>, but this
would not prevent duplication compared to <structname>cities</structname>.
</para>
</listitem>
<listitem>
<para>
Similarly, if we were to specify that
<structname>cities</structname>.<structfield>name</structfield> <literal>REFERENCES</literal> some
other table, this constraint would not automatically propagate to
<structname>capitals</structname>. In this case you could work around it by
manually adding the same <literal>REFERENCES</literal> constraint to
<structname>capitals</structname>.
</para>
</listitem>
<listitem>
<para>
Specifying that another table's column <literal>REFERENCES
cities(name)</literal> would allow the other table to contain city names, but
not capital names. There is no good workaround for this case.
</para>
</listitem>
</itemizedlist>
Some functionality not implemented for inheritance hierarchies is
implemented for declarative partitioning.
Considerable care is needed in deciding whether partitioning with legacy
inheritance is useful for your application.
</para>
</sect2>
</sect1>
<sect1 id="ddl-partitioning">
<title>Table Partitioning</title>
<indexterm>
<primary>partitioning</primary>
</indexterm>
<indexterm>
<primary>table</primary>
<secondary>partitioning</secondary>
</indexterm>
<indexterm>
<primary>partitioned table</primary>
</indexterm>
<para>
<productname>PostgreSQL</productname> supports basic table
partitioning. This section describes why and how to implement
partitioning as part of your database design.
</para>
<sect2 id="ddl-partitioning-overview">
<title>Overview</title>
<para>
Partitioning refers to splitting what is logically one large table into
smaller physical pieces. Partitioning can provide several benefits:
<itemizedlist>
<listitem>
<para>
Query performance can be improved dramatically in certain situations,
particularly when most of the heavily accessed rows of the table are in a
single partition or a small number of partitions. Partitioning
effectively substitutes for the upper tree levels of indexes,
making it more likely that the heavily-used parts of the indexes
fit in memory.
</para>
</listitem>
<listitem>
<para>
When queries or updates access a large percentage of a single
partition, performance can be improved by using a
sequential scan of that partition instead of using an
index, which would require random-access reads scattered across the
whole table.
</para>
</listitem>
<listitem>
<para>
Bulk loads and deletes can be accomplished by adding or removing
partitions, if the usage pattern is accounted for in the
partitioning design. Dropping an individual partition
using <command>DROP TABLE</command>, or doing <command>ALTER TABLE
DETACH PARTITION</command>, is far faster than a bulk
operation. These commands also entirely avoid the
<command>VACUUM</command> overhead caused by a bulk <command>DELETE</command>.
</para>
</listitem>
<listitem>
<para>
Seldom-used data can be migrated to cheaper and slower storage media.
</para>
</listitem>
</itemizedlist>
These benefits will normally be worthwhile only when a table would
otherwise be very large. The exact point at which a table will
benefit from partitioning depends on the application, although a
rule of thumb is that the size of the table should exceed the physical
memory of the database server.
</para>
<para>
<productname>PostgreSQL</productname> offers built-in support for the
following forms of partitioning:
<variablelist>
<varlistentry>
<term>Range Partitioning</term>
<listitem>
<para>
The table is partitioned into <quote>ranges</quote> defined
by a key column or set of columns, with no overlap between
the ranges of values assigned to different partitions. For
example, one might partition by date ranges, or by ranges of
identifiers for particular business objects.
Each range's bounds are understood as being inclusive at the
lower end and exclusive at the upper end. For example, if one
partition's range is from <literal>1</literal>
to <literal>10</literal>, and the next one's range is
from <literal>10</literal> to <literal>20</literal>, then
value <literal>10</literal> belongs to the second partition not
the first.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>List Partitioning</term>
<listitem>
<para>
The table is partitioned by explicitly listing which key value(s)
appear in each partition.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Hash Partitioning</term>
<listitem>
<para>
The table is partitioned by specifying a modulus and a remainder for
each partition. Each partition will hold the rows for which the hash
value of the partition key divided by the specified modulus will
produce the specified remainder.
</para>
</listitem>
</varlistentry>
</variablelist>
If your application needs to use other forms of partitioning not listed
above, alternative methods such as inheritance and
<literal>UNION ALL</literal> views can be used instead. Such methods
offer flexibility but do not have some of the performance benefits
of built-in declarative partitioning.
</para>
</sect2>
<sect2 id="ddl-partitioning-declarative">
<title>Declarative Partitioning</title>
<para>
<productname>PostgreSQL</productname> allows you to declare
that a table is divided into partitions. The table that is divided
is referred to as a <firstterm>partitioned table</firstterm>. The
declaration includes the <firstterm>partitioning method</firstterm>
as described above, plus a list of columns or expressions to be used
as the <firstterm>partition key</firstterm>.
</para>
<para>
The partitioned table itself is a <quote>virtual</quote> table having
no storage of its own. Instead, the storage belongs
to <firstterm>partitions</firstterm>, which are otherwise-ordinary
tables associated with the partitioned table.
Each partition stores a subset of the data as defined by its
<firstterm>partition bounds</firstterm>.
All rows inserted into a partitioned table will be routed to the
appropriate one of the partitions based on the values of the partition
key column(s).
Updating the partition key of a row will cause it to be moved into a
different partition if it no longer satisfies the partition bounds
of its original partition.
</para>
<para>
Partitions may themselves be defined as partitioned tables, resulting
in <firstterm>sub-partitioning</firstterm>. Although all partitions
must have the same columns as their partitioned parent, partitions may
have their
own indexes, constraints and default values, distinct from those of other
partitions. See <xref linkend="sql-createtable"/> for more details on
creating partitioned tables and partitions.
</para>
<para>
It is not possible to turn a regular table into a partitioned table or
vice versa. However, it is possible to add an existing regular or
partitioned table as a partition of a partitioned table, or remove a
partition from a partitioned table turning it into a standalone table;
this can simplify and speed up many maintenance processes.
See <xref linkend="sql-altertable"/> to learn more about the
<command>ATTACH PARTITION</command> and <command>DETACH PARTITION</command>
sub-commands.
</para>
<para>
Partitions can also be <link linkend="ddl-foreign-data">foreign
tables</link>, although considerable care is needed because it is then
the user's responsibility that the contents of the foreign table
satisfy the partitioning rule. There are some other restrictions as
well. See <xref linkend="sql-createforeigntable"/> for more
information.
</para>
<sect3 id="ddl-partitioning-declarative-example">
<title>Example</title>
<para>
Suppose we are constructing a database for a large ice cream company.
The company measures peak temperatures every day as well as ice cream
sales in each region. Conceptually, we want a table like:
<programlisting>
CREATE TABLE measurement (
city_id int not null,
logdate date not null,
peaktemp int,
unitsales int
);
</programlisting>
We know that most queries will access just the last week's, month's or
quarter's data, since the main use of this table will be to prepare
online reports for management. To reduce the amount of old data that
needs to be stored, we decide to keep only the most recent 3 years
worth of data. At the beginning of each month we will remove the oldest
month's data. In this situation we can use partitioning to help us meet
all of our different requirements for the measurements table.
</para>
<para>
To use declarative partitioning in this case, use the following steps:
<orderedlist spacing="compact">
<listitem>
<para>
Create the <structname>measurement</structname> table as a partitioned
table by specifying the <literal>PARTITION BY</literal> clause, which
includes the partitioning method (<literal>RANGE</literal> in this
case) and the list of column(s) to use as the partition key.
<programlisting>
CREATE TABLE measurement (
city_id int not null,
logdate date not null,
peaktemp int,
unitsales int
) PARTITION BY RANGE (logdate);
</programlisting>
</para>
</listitem>
<listitem>
<para>
Create partitions. Each partition's definition must specify bounds
that correspond to the partitioning method and partition key of the
parent. Note that specifying bounds such that the new partition's
values would overlap with those in one or more existing partitions will
cause an error.
</para>
<para>
Partitions thus created are in every way normal
<productname>PostgreSQL</productname>
tables (or, possibly, foreign tables). It is possible to specify a
tablespace and storage parameters for each partition separately.
</para>
<para>
For our example, each partition should hold one month's worth of
data, to match the requirement of deleting one month's data at a
time. So the commands might look like:
<programlisting>
CREATE TABLE measurement_y2006m02 PARTITION OF measurement
FOR VALUES FROM ('2006-02-01') TO ('2006-03-01');
CREATE TABLE measurement_y2006m03 PARTITION OF measurement
FOR VALUES FROM ('2006-03-01') TO ('2006-04-01');
...
CREATE TABLE measurement_y2007m11 PARTITION OF measurement
FOR VALUES FROM ('2007-11-01') TO ('2007-12-01');
CREATE TABLE measurement_y2007m12 PARTITION OF measurement
FOR VALUES FROM ('2007-12-01') TO ('2008-01-01')
TABLESPACE fasttablespace;
CREATE TABLE measurement_y2008m01 PARTITION OF measurement
FOR VALUES FROM ('2008-01-01') TO ('2008-02-01')
WITH (parallel_workers = 4)
TABLESPACE fasttablespace;
</programlisting>
(Recall that adjacent partitions can share a bound value, since
range upper bounds are treated as exclusive bounds.)
</para>
<para>
If you wish to implement sub-partitioning, again specify the
<literal>PARTITION BY</literal> clause in the commands used to create
individual partitions, for example:
<programlisting>
CREATE TABLE measurement_y2006m02 PARTITION OF measurement
FOR VALUES FROM ('2006-02-01') TO ('2006-03-01')
PARTITION BY RANGE (peaktemp);
</programlisting>
After creating partitions of <structname>measurement_y2006m02</structname>,
any data inserted into <structname>measurement</structname> that is mapped to
<structname>measurement_y2006m02</structname> (or data that is
directly inserted into <structname>measurement_y2006m02</structname>,
which is allowed provided its partition constraint is satisfied)
will be further redirected to one of its
partitions based on the <structfield>peaktemp</structfield> column. The partition
key specified may overlap with the parent's partition key, although
care should be taken when specifying the bounds of a sub-partition
such that the set of data it accepts constitutes a subset of what
the partition's own bounds allow; the system does not try to check
whether that's really the case.
</para>
<para>
Inserting data into the parent table that does not map
to one of the existing partitions will cause an error; an appropriate
partition must be added manually.
</para>
<para>
It is not necessary to manually create table constraints describing
the partition boundary conditions for partitions. Such constraints
will be created automatically.
</para>
</listitem>
<listitem>
<para>
Create an index on the key column(s), as well as any other indexes you
might want, on the partitioned table. (The key index is not strictly
necessary, but in most scenarios it is helpful.)
This automatically creates a matching index on each partition, and
any partitions you create or attach later will also have such an
index.
An index or unique constraint declared on a partitioned table
is <quote>virtual</quote> in the same way that the partitioned table
is: the actual data is in child indexes on the individual partition
tables.
<programlisting>
CREATE INDEX ON measurement (logdate);
</programlisting>
</para>
</listitem>
<listitem>
<para>
Ensure that the <xref linkend="guc-enable-partition-pruning"/>
configuration parameter is not disabled in <filename>postgresql.conf</filename>.
If it is, queries will not be optimized as desired.
</para>
</listitem>
</orderedlist>
</para>
<para>
In the above example we would be creating a new partition each month, so
it might be wise to write a script that generates the required DDL
automatically.
</para>
</sect3>
<sect3 id="ddl-partitioning-declarative-maintenance">
<title>Partition Maintenance</title>
<para>
Normally the set of partitions established when initially defining the
table is not intended to remain static. It is common to want to
remove partitions holding old data and periodically add new partitions for
new data. One of the most important advantages of partitioning is
precisely that it allows this otherwise painful task to be executed
nearly instantaneously by manipulating the partition structure, rather
than physically moving large amounts of data around.
</para>
<para>
The simplest option for removing old data is to drop the partition that
is no longer necessary:
<programlisting>
DROP TABLE measurement_y2006m02;
</programlisting>
This can very quickly delete millions of records because it doesn't have
to individually delete every record. Note however that the above command
requires taking an <literal>ACCESS EXCLUSIVE</literal> lock on the parent
table.
</para>
<para>
Another option that is often preferable is to remove the partition from
the partitioned table but retain access to it as a table in its own
right. This has two forms:
<programlisting>
ALTER TABLE measurement DETACH PARTITION measurement_y2006m02;
ALTER TABLE measurement DETACH PARTITION measurement_y2006m02 CONCURRENTLY;
</programlisting>
These allow further operations to be performed on the data before
it is dropped. For example, this is often a useful time to back up
the data using <command>COPY</command>, <application>pg_dump</application>, or
similar tools. It might also be a useful time to aggregate data
into smaller formats, perform other data manipulations, or run
reports. The first form of the command requires an
<literal>ACCESS EXCLUSIVE</literal> lock on the parent table.
Adding the <literal>CONCURRENTLY</literal> qualifier as in the second
form allows the detach operation to require only
<literal>SHARE UPDATE EXCLUSIVE</literal> lock on the parent table, but see
<link linkend="sql-altertable-detach-partition"><literal>ALTER TABLE ... DETACH PARTITION</literal></link>
for details on the restrictions.
</para>
<para>
Similarly we can add a new partition to handle new data. We can create an
empty partition in the partitioned table just as the original partitions
were created above:
<programlisting>
CREATE TABLE measurement_y2008m02 PARTITION OF measurement
FOR VALUES FROM ('2008-02-01') TO ('2008-03-01')
TABLESPACE fasttablespace;
</programlisting>
As an alternative, it is sometimes more convenient to create the
new table outside the partition structure, and make it a proper
partition later. This allows new data to be loaded, checked, and
transformed prior to it appearing in the partitioned table.
The <literal>CREATE TABLE ... LIKE</literal> option is helpful
to avoid tediously repeating the parent table's definition:
<programlisting>
CREATE TABLE measurement_y2008m02
(LIKE measurement INCLUDING DEFAULTS INCLUDING CONSTRAINTS)
TABLESPACE fasttablespace;
ALTER TABLE measurement_y2008m02 ADD CONSTRAINT y2008m02
CHECK ( logdate >= DATE '2008-02-01' AND logdate < DATE '2008-03-01' );
\copy measurement_y2008m02 from 'measurement_y2008m02'
-- possibly some other data preparation work
ALTER TABLE measurement ATTACH PARTITION measurement_y2008m02
FOR VALUES FROM ('2008-02-01') TO ('2008-03-01' );
</programlisting>
</para>
<para>
The <command>ATTACH PARTITION</command> command requires taking a
<literal>SHARE UPDATE EXCLUSIVE</literal> lock on the partitioned table.
</para>
<para>
Before running the <command>ATTACH PARTITION</command> command, it is
recommended to create a <literal>CHECK</literal> constraint on the table to
be attached that matches the expected partition constraint, as
illustrated above. That way, the system will be able to skip the scan
which is otherwise needed to validate the implicit
partition constraint. Without the <literal>CHECK</literal> constraint,
the table will be scanned to validate the partition constraint while
holding an <literal>ACCESS EXCLUSIVE</literal> lock on that partition.
It is recommended to drop the now-redundant <literal>CHECK</literal>
constraint after the <command>ATTACH PARTITION</command> is complete. If
the table being attached is itself a partitioned table, then each of its
sub-partitions will be recursively locked and scanned until either a
suitable <literal>CHECK</literal> constraint is encountered or the leaf
partitions are reached.
</para>
<para>
Similarly, if the partitioned table has a <literal>DEFAULT</literal>
partition, it is recommended to create a <literal>CHECK</literal>
constraint which excludes the to-be-attached partition's constraint. If
this is not done then the <literal>DEFAULT</literal> partition will be
scanned to verify that it contains no records which should be located in
the partition being attached. This operation will be performed whilst
holding an <literal>ACCESS EXCLUSIVE</literal> lock on the <literal>
DEFAULT</literal> partition. If the <literal>DEFAULT</literal> partition
is itself a partitioned table, then each of its partitions will be
recursively checked in the same way as the table being attached, as
mentioned above.
</para>
<para>
As explained above, it is possible to create indexes on partitioned tables
so that they are applied automatically to the entire hierarchy.
This is very
convenient, as not only will the existing partitions become indexed, but
also any partitions that are created in the future will. One limitation is
that it's not possible to use the <literal>CONCURRENTLY</literal>
qualifier when creating such a partitioned index. To avoid long lock
times, it is possible to use <command>CREATE INDEX ON ONLY</command>
the partitioned table; such an index is marked invalid, and the partitions
do not get the index applied automatically. The indexes on partitions can
be created individually using <literal>CONCURRENTLY</literal>, and then
<firstterm>attached</firstterm> to the index on the parent using
<command>ALTER INDEX .. ATTACH PARTITION</command>. Once indexes for all
partitions are attached to the parent index, the parent index is marked
valid automatically. Example:
<programlisting>
CREATE INDEX measurement_usls_idx ON ONLY measurement (unitsales);
CREATE INDEX measurement_usls_200602_idx
ON measurement_y2006m02 (unitsales);
ALTER INDEX measurement_usls_idx
ATTACH PARTITION measurement_usls_200602_idx;
...
</programlisting>
This technique can be used with <literal>UNIQUE</literal> and
<literal>PRIMARY KEY</literal> constraints too; the indexes are created
implicitly when the constraint is created. Example:
<programlisting>
ALTER TABLE ONLY measurement ADD UNIQUE (city_id, logdate);
ALTER TABLE measurement_y2006m02 ADD UNIQUE (city_id, logdate);
ALTER INDEX measurement_city_id_logdate_key
ATTACH PARTITION measurement_y2006m02_city_id_logdate_key;
...
</programlisting>
</para>
</sect3>
<sect3 id="ddl-partitioning-declarative-limitations">
<title>Limitations</title>
<para>
The following limitations apply to partitioned tables:
<itemizedlist>
<listitem>
<para>
Unique constraints (and hence primary keys) on partitioned tables must
include all the partition key columns. This limitation exists because
the individual indexes making up the constraint can only directly
enforce uniqueness within their own partitions; therefore, the
partition structure itself must guarantee that there are not
duplicates in different partitions.
</para>
</listitem>
<listitem>
<para>
There is no way to create an exclusion constraint spanning the
whole partitioned table. It is only possible to put such a
constraint on each leaf partition individually. Again, this
limitation stems from not being able to enforce cross-partition
restrictions.
</para>
</listitem>
<listitem>
<para>
<literal>BEFORE ROW</literal> triggers on <literal>INSERT</literal>
cannot change which partition is the final destination for a new row.
</para>
</listitem>
<listitem>
<para>
Mixing temporary and permanent relations in the same partition tree is
not allowed. Hence, if the partitioned table is permanent, so must be
its partitions and likewise if the partitioned table is temporary. When
using temporary relations, all members of the partition tree have to be
from the same session.
</para>
</listitem>
</itemizedlist>
</para>
<para>
Individual partitions are linked to their partitioned table using
inheritance behind-the-scenes. However, it is not possible to use
all of the generic features of inheritance with declaratively
partitioned tables or their partitions, as discussed below. Notably,
a partition cannot have any parents other than the partitioned table
it is a partition of, nor can a table inherit from both a partitioned
table and a regular table. That means partitioned tables and their
partitions never share an inheritance hierarchy with regular tables.
</para>
<para>
Since a partition hierarchy consisting of the partitioned table and its
partitions is still an inheritance hierarchy,
<structfield>tableoid</structfield> and all the normal rules of
inheritance apply as described in <xref linkend="ddl-inherit"/>, with
a few exceptions:
<itemizedlist>
<listitem>
<para>
Partitions cannot have columns that are not present in the parent. It
is not possible to specify columns when creating partitions with
<command>CREATE TABLE</command>, nor is it possible to add columns to
partitions after-the-fact using <command>ALTER TABLE</command>.
Tables may be added as a partition with <command>ALTER TABLE
... ATTACH PARTITION</command> only if their columns exactly match
the parent.
</para>
</listitem>
<listitem>
<para>
Both <literal>CHECK</literal> and <literal>NOT NULL</literal>
constraints of a partitioned table are always inherited by all its
partitions. <literal>CHECK</literal> constraints that are marked
<literal>NO INHERIT</literal> are not allowed to be created on
partitioned tables.
You cannot drop a <literal>NOT NULL</literal> constraint on a
partition's column if the same constraint is present in the parent
table.
</para>
</listitem>
<listitem>
<para>
Using <literal>ONLY</literal> to add or drop a constraint on only
the partitioned table is supported as long as there are no
partitions. Once partitions exist, using <literal>ONLY</literal>
will result in an error. Instead, constraints on the partitions
themselves can be added and (if they are not present in the parent
table) dropped.
</para>
</listitem>
<listitem>
<para>
As a partitioned table does not have any data itself, attempts to use
<command>TRUNCATE</command> <literal>ONLY</literal> on a partitioned
table will always return an error.
</para>
</listitem>
</itemizedlist>
</para>
</sect3>
</sect2>
<sect2 id="ddl-partitioning-using-inheritance">
<title>Partitioning Using Inheritance</title>
<para>
While the built-in declarative partitioning is suitable for most
common use cases, there are some circumstances where a more flexible
approach may be useful. Partitioning can be implemented using table
inheritance, which allows for several features not supported
by declarative partitioning, such as:
<itemizedlist>
<listitem>
<para>
For declarative partitioning, partitions must have exactly the same set
of columns as the partitioned table, whereas with table inheritance,
child tables may have extra columns not present in the parent.
</para>
</listitem>
<listitem>
<para>
Table inheritance allows for multiple inheritance.
</para>
</listitem>
<listitem>
<para>
Declarative partitioning only supports range, list and hash
partitioning, whereas table inheritance allows data to be divided in a
manner of the user's choosing. (Note, however, that if constraint
exclusion is unable to prune child tables effectively, query performance
might be poor.)
</para>
</listitem>
</itemizedlist>
</para>
<sect3 id="ddl-partitioning-inheritance-example">
<title>Example</title>
<para>
This example builds a partitioning structure equivalent to the
declarative partitioning example above. Use
the following steps:
<orderedlist spacing="compact">
<listitem>
<para>
Create the <quote>root</quote> table, from which all of the
<quote>child</quote> tables will inherit. This table will contain no data. Do not
define any check constraints on this table, unless you intend them
to be applied equally to all child tables. There is no point in
defining any indexes or unique constraints on it, either. For our
example, the root table is the <structname>measurement</structname>
table as originally defined:
<programlisting>
CREATE TABLE measurement (
city_id int not null,
logdate date not null,
peaktemp int,
unitsales int
);
</programlisting>
</para>
</listitem>
<listitem>
<para>
Create several <quote>child</quote> tables that each inherit from
the root table. Normally, these tables will not add any columns
to the set inherited from the root. Just as with declarative
partitioning, these tables are in every way normal
<productname>PostgreSQL</productname> tables (or foreign tables).
</para>
<para>
<programlisting>
CREATE TABLE measurement_y2006m02 () INHERITS (measurement);
CREATE TABLE measurement_y2006m03 () INHERITS (measurement);
...
CREATE TABLE measurement_y2007m11 () INHERITS (measurement);
CREATE TABLE measurement_y2007m12 () INHERITS (measurement);
CREATE TABLE measurement_y2008m01 () INHERITS (measurement);
</programlisting>
</para>
</listitem>
<listitem>
<para>
Add non-overlapping table constraints to the child tables to
define the allowed key values in each.
</para>
<para>
Typical examples would be:
<programlisting>
CHECK ( x = 1 )
CHECK ( county IN ( 'Oxfordshire', 'Buckinghamshire', 'Warwickshire' ))
CHECK ( outletID >= 100 AND outletID < 200 )
</programlisting>
Ensure that the constraints guarantee that there is no overlap
between the key values permitted in different child tables. A common
mistake is to set up range constraints like:
<programlisting>
CHECK ( outletID BETWEEN 100 AND 200 )
CHECK ( outletID BETWEEN 200 AND 300 )
</programlisting>
This is wrong since it is not clear which child table the key
value 200 belongs in.
Instead, ranges should be defined in this style:
<programlisting>
CREATE TABLE measurement_y2006m02 (
CHECK ( logdate >= DATE '2006-02-01' AND logdate < DATE '2006-03-01' )
) INHERITS (measurement);
CREATE TABLE measurement_y2006m03 (
CHECK ( logdate >= DATE '2006-03-01' AND logdate < DATE '2006-04-01' )
) INHERITS (measurement);
...
CREATE TABLE measurement_y2007m11 (
CHECK ( logdate >= DATE '2007-11-01' AND logdate < DATE '2007-12-01' )
) INHERITS (measurement);
CREATE TABLE measurement_y2007m12 (
CHECK ( logdate >= DATE '2007-12-01' AND logdate < DATE '2008-01-01' )
) INHERITS (measurement);
CREATE TABLE measurement_y2008m01 (
CHECK ( logdate >= DATE '2008-01-01' AND logdate < DATE '2008-02-01' )
) INHERITS (measurement);
</programlisting>
</para>
</listitem>
<listitem>
<para>
For each child table, create an index on the key column(s),
as well as any other indexes you might want.
<programlisting>
CREATE INDEX measurement_y2006m02_logdate ON measurement_y2006m02 (logdate);
CREATE INDEX measurement_y2006m03_logdate ON measurement_y2006m03 (logdate);
CREATE INDEX measurement_y2007m11_logdate ON measurement_y2007m11 (logdate);
CREATE INDEX measurement_y2007m12_logdate ON measurement_y2007m12 (logdate);
CREATE INDEX measurement_y2008m01_logdate ON measurement_y2008m01 (logdate);
</programlisting>
</para>
</listitem>
<listitem>
<para>
We want our application to be able to say <literal>INSERT INTO
measurement ...</literal> and have the data be redirected into the
appropriate child table. We can arrange that by attaching
a suitable trigger function to the root table.
If data will be added only to the latest child, we can
use a very simple trigger function:
<programlisting>
CREATE OR REPLACE FUNCTION measurement_insert_trigger()
RETURNS TRIGGER AS $$
BEGIN
INSERT INTO measurement_y2008m01 VALUES (NEW.*);
RETURN NULL;
END;
$$
LANGUAGE plpgsql;
</programlisting>
</para>
<para>
After creating the function, we create a trigger which
calls the trigger function:
<programlisting>
CREATE TRIGGER insert_measurement_trigger
BEFORE INSERT ON measurement
FOR EACH ROW EXECUTE FUNCTION measurement_insert_trigger();
</programlisting>
We must redefine the trigger function each month so that it always
inserts into the current child table. The trigger definition does
not need to be updated, however.
</para>
<para>
We might want to insert data and have the server automatically
locate the child table into which the row should be added. We
could do this with a more complex trigger function, for example:
<programlisting>
CREATE OR REPLACE FUNCTION measurement_insert_trigger()
RETURNS TRIGGER AS $$
BEGIN
IF ( NEW.logdate >= DATE '2006-02-01' AND
NEW.logdate < DATE '2006-03-01' ) THEN
INSERT INTO measurement_y2006m02 VALUES (NEW.*);
ELSIF ( NEW.logdate >= DATE '2006-03-01' AND
NEW.logdate < DATE '2006-04-01' ) THEN
INSERT INTO measurement_y2006m03 VALUES (NEW.*);
...
ELSIF ( NEW.logdate >= DATE '2008-01-01' AND
NEW.logdate < DATE '2008-02-01' ) THEN
INSERT INTO measurement_y2008m01 VALUES (NEW.*);
ELSE
RAISE EXCEPTION 'Date out of range. Fix the measurement_insert_trigger() function!';
END IF;
RETURN NULL;
END;
$$
LANGUAGE plpgsql;
</programlisting>
The trigger definition is the same as before.
Note that each <literal>IF</literal> test must exactly match the
<literal>CHECK</literal> constraint for its child table.
</para>
<para>
While this function is more complex than the single-month case,
it doesn't need to be updated as often, since branches can be
added in advance of being needed.
</para>
<note>
<para>
In practice, it might be best to check the newest child first,
if most inserts go into that child. For simplicity, we have
shown the trigger's tests in the same order as in other parts
of this example.
</para>
</note>
<para>
A different approach to redirecting inserts into the appropriate
child table is to set up rules, instead of a trigger, on the
root table. For example:
<programlisting>
CREATE RULE measurement_insert_y2006m02 AS
ON INSERT TO measurement WHERE
( logdate >= DATE '2006-02-01' AND logdate < DATE '2006-03-01' )
DO INSTEAD
INSERT INTO measurement_y2006m02 VALUES (NEW.*);
...
CREATE RULE measurement_insert_y2008m01 AS
ON INSERT TO measurement WHERE
( logdate >= DATE '2008-01-01' AND logdate < DATE '2008-02-01' )
DO INSTEAD
INSERT INTO measurement_y2008m01 VALUES (NEW.*);
</programlisting>
A rule has significantly more overhead than a trigger, but the
overhead is paid once per query rather than once per row, so this
method might be advantageous for bulk-insert situations. In most
cases, however, the trigger method will offer better performance.
</para>
<para>
Be aware that <command>COPY</command> ignores rules. If you want to
use <command>COPY</command> to insert data, you'll need to copy into the
correct child table rather than directly into the root. <command>COPY</command>
does fire triggers, so you can use it normally if you use the trigger
approach.
</para>
<para>
Another disadvantage of the rule approach is that there is no simple
way to force an error if the set of rules doesn't cover the insertion
date; the data will silently go into the root table instead.
</para>
</listitem>
<listitem>
<para>
Ensure that the <xref linkend="guc-constraint-exclusion"/>
configuration parameter is not disabled in
<filename>postgresql.conf</filename>; otherwise
child tables may be accessed unnecessarily.
</para>
</listitem>
</orderedlist>
</para>
<para>
As we can see, a complex table hierarchy could require a
substantial amount of DDL. In the above example we would be creating
a new child table each month, so it might be wise to write a script that
generates the required DDL automatically.
</para>
</sect3>
<sect3 id="ddl-partitioning-inheritance-maintenance">
<title>Maintenance for Inheritance Partitioning</title>
<para>
To remove old data quickly, simply drop the child table that is no longer
necessary:
<programlisting>
DROP TABLE measurement_y2006m02;
</programlisting>
</para>
<para>
To remove the child table from the inheritance hierarchy table but retain access to
it as a table in its own right:
<programlisting>
ALTER TABLE measurement_y2006m02 NO INHERIT measurement;
</programlisting>
</para>
<para>
To add a new child table to handle new data, create an empty child table
just as the original children were created above:
<programlisting>
CREATE TABLE measurement_y2008m02 (
CHECK ( logdate >= DATE '2008-02-01' AND logdate < DATE '2008-03-01' )
) INHERITS (measurement);
</programlisting>
Alternatively, one may want to create and populate the new child table
before adding it to the table hierarchy. This could allow data to be
loaded, checked, and transformed before being made visible to queries on
the parent table.
<programlisting>
CREATE TABLE measurement_y2008m02
(LIKE measurement INCLUDING DEFAULTS INCLUDING CONSTRAINTS);
ALTER TABLE measurement_y2008m02 ADD CONSTRAINT y2008m02
CHECK ( logdate >= DATE '2008-02-01' AND logdate < DATE '2008-03-01' );
\copy measurement_y2008m02 from 'measurement_y2008m02'
-- possibly some other data preparation work
ALTER TABLE measurement_y2008m02 INHERIT measurement;
</programlisting>
</para>
</sect3>
<sect3 id="ddl-partitioning-inheritance-caveats">
<title>Caveats</title>
<para>
The following caveats apply to partitioning implemented using
inheritance:
<itemizedlist>
<listitem>
<para>
There is no automatic way to verify that all of the
<literal>CHECK</literal> constraints are mutually
exclusive. It is safer to create code that generates
child tables and creates and/or modifies associated objects than
to write each by hand.
</para>
</listitem>
<listitem>
<para>
Indexes and foreign key constraints apply to single tables and not
to their inheritance children, hence they have some
<link linkend="ddl-inherit-caveats">caveats</link> to be aware of.
</para>
</listitem>
<listitem>
<para>
The schemes shown here assume that the values of a row's key column(s)
never change, or at least do not change enough to require it to move to another partition.
An <command>UPDATE</command> that attempts
to do that will fail because of the <literal>CHECK</literal> constraints.
If you need to handle such cases, you can put suitable update triggers
on the child tables, but it makes management of the structure
much more complicated.
</para>
</listitem>
<listitem>
<para>
If you are using manual <command>VACUUM</command> or
<command>ANALYZE</command> commands, don't forget that
you need to run them on each child table individually. A command like:
<programlisting>
ANALYZE measurement;
</programlisting>
will only process the root table.
</para>
</listitem>
<listitem>
<para>
<command>INSERT</command> statements with <literal>ON CONFLICT</literal>
clauses are unlikely to work as expected, as the <literal>ON CONFLICT</literal>
action is only taken in case of unique violations on the specified
target relation, not its child relations.
</para>
</listitem>
<listitem>
<para>
Triggers or rules will be needed to route rows to the desired
child table, unless the application is explicitly aware of the
partitioning scheme. Triggers may be complicated to write, and will
be much slower than the tuple routing performed internally by
declarative partitioning.
</para>
</listitem>
</itemizedlist>
</para>
</sect3>
</sect2>
<sect2 id="ddl-partition-pruning">
<title>Partition Pruning</title>
<indexterm>
<primary>partition pruning</primary>
</indexterm>
<para>
<firstterm>Partition pruning</firstterm> is a query optimization technique
that improves performance for declaratively partitioned tables.
As an example:
<programlisting>
SET enable_partition_pruning = on; -- the default
SELECT count(*) FROM measurement WHERE logdate >= DATE '2008-01-01';
</programlisting>
Without partition pruning, the above query would scan each of the
partitions of the <structname>measurement</structname> table. With
partition pruning enabled, the planner will examine the definition
of each partition and prove that the partition need not
be scanned because it could not contain any rows meeting the query's
<literal>WHERE</literal> clause. When the planner can prove this, it
excludes (<firstterm>prunes</firstterm>) the partition from the query
plan.
</para>
<para>
By using the EXPLAIN command and the <xref
linkend="guc-enable-partition-pruning"/> configuration parameter, it's
possible to show the difference between a plan for which partitions have
been pruned and one for which they have not. A typical unoptimized
plan for this type of table setup is:
<programlisting>
SET enable_partition_pruning = off;
EXPLAIN SELECT count(*) FROM measurement WHERE logdate >= DATE '2008-01-01';
QUERY PLAN
-------------------------------------------------------------------&zwsp;----------------
Aggregate (cost=188.76..188.77 rows=1 width=8)
-> Append (cost=0.00..181.05 rows=3085 width=0)
-> Seq Scan on measurement_y2006m02 (cost=0.00..33.12 rows=617 width=0)
Filter: (logdate >= '2008-01-01'::date)
-> Seq Scan on measurement_y2006m03 (cost=0.00..33.12 rows=617 width=0)
Filter: (logdate >= '2008-01-01'::date)
...
-> Seq Scan on measurement_y2007m11 (cost=0.00..33.12 rows=617 width=0)
Filter: (logdate >= '2008-01-01'::date)
-> Seq Scan on measurement_y2007m12 (cost=0.00..33.12 rows=617 width=0)
Filter: (logdate >= '2008-01-01'::date)
-> Seq Scan on measurement_y2008m01 (cost=0.00..33.12 rows=617 width=0)
Filter: (logdate >= '2008-01-01'::date)
</programlisting>
Some or all of the partitions might use index scans instead of
full-table sequential scans, but the point here is that there
is no need to scan the older partitions at all to answer this query.
When we enable partition pruning, we get a significantly
cheaper plan that will deliver the same answer:
<programlisting>
SET enable_partition_pruning = on;
EXPLAIN SELECT count(*) FROM measurement WHERE logdate >= DATE '2008-01-01';
QUERY PLAN
-------------------------------------------------------------------&zwsp;----------------
Aggregate (cost=37.75..37.76 rows=1 width=8)
-> Seq Scan on measurement_y2008m01 (cost=0.00..33.12 rows=617 width=0)
Filter: (logdate >= '2008-01-01'::date)
</programlisting>
</para>
<para>
Note that partition pruning is driven only by the constraints defined
implicitly by the partition keys, not by the presence of indexes.
Therefore it isn't necessary to define indexes on the key columns.
Whether an index needs to be created for a given partition depends on
whether you expect that queries that scan the partition will
generally scan a large part of the partition or just a small part.
An index will be helpful in the latter case but not the former.
</para>
<para>
Partition pruning can be performed not only during the planning of a
given query, but also during its execution. This is useful as it can
allow more partitions to be pruned when clauses contain expressions
whose values are not known at query planning time, for example,
parameters defined in a <command>PREPARE</command> statement, using a
value obtained from a subquery, or using a parameterized value on the
inner side of a nested loop join. Partition pruning during execution
can be performed at any of the following times:
<itemizedlist>
<listitem>
<para>
During initialization of the query plan. Partition pruning can be
performed here for parameter values which are known during the
initialization phase of execution. Partitions which are pruned
during this stage will not show up in the query's
<command>EXPLAIN</command> or <command>EXPLAIN ANALYZE</command>.
It is possible to determine the number of partitions which were
removed during this phase by observing the
<quote>Subplans Removed</quote> property in the
<command>EXPLAIN</command> output.
</para>
</listitem>
<listitem>
<para>
During actual execution of the query plan. Partition pruning may
also be performed here to remove partitions using values which are
only known during actual query execution. This includes values
from subqueries and values from execution-time parameters such as
those from parameterized nested loop joins. Since the value of
these parameters may change many times during the execution of the
query, partition pruning is performed whenever one of the
execution parameters being used by partition pruning changes.
Determining if partitions were pruned during this phase requires
careful inspection of the <literal>loops</literal> property in
the <command>EXPLAIN ANALYZE</command> output. Subplans
corresponding to different partitions may have different values
for it depending on how many times each of them was pruned during
execution. Some may be shown as <literal>(never executed)</literal>
if they were pruned every time.
</para>
</listitem>
</itemizedlist>
</para>
<para>
Partition pruning can be disabled using the
<xref linkend="guc-enable-partition-pruning"/> setting.
</para>
</sect2>
<sect2 id="ddl-partitioning-constraint-exclusion">
<title>Partitioning and Constraint Exclusion</title>
<indexterm>
<primary>constraint exclusion</primary>
</indexterm>
<para>
<firstterm>Constraint exclusion</firstterm> is a query optimization
technique similar to partition pruning. While it is primarily used
for partitioning implemented using the legacy inheritance method, it can be
used for other purposes, including with declarative partitioning.
</para>
<para>
Constraint exclusion works in a very similar way to partition
pruning, except that it uses each table's <literal>CHECK</literal>
constraints — which gives it its name — whereas partition
pruning uses the table's partition bounds, which exist only in the
case of declarative partitioning. Another difference is that
constraint exclusion is only applied at plan time; there is no attempt
to remove partitions at execution time.
</para>
<para>
The fact that constraint exclusion uses <literal>CHECK</literal>
constraints, which makes it slow compared to partition pruning, can
sometimes be used as an advantage: because constraints can be defined
even on declaratively-partitioned tables, in addition to their internal
partition bounds, constraint exclusion may be able
to elide additional partitions from the query plan.
</para>
<para>
The default (and recommended) setting of
<xref linkend="guc-constraint-exclusion"/> is neither
<literal>on</literal> nor <literal>off</literal>, but an intermediate setting
called <literal>partition</literal>, which causes the technique to be
applied only to queries that are likely to be working on inheritance partitioned
tables. The <literal>on</literal> setting causes the planner to examine
<literal>CHECK</literal> constraints in all queries, even simple ones that
are unlikely to benefit.
</para>
<para>
The following caveats apply to constraint exclusion:
<itemizedlist>
<listitem>
<para>
Constraint exclusion is only applied during query planning, unlike
partition pruning, which can also be applied during query execution.
</para>
</listitem>
<listitem>
<para>
Constraint exclusion only works when the query's <literal>WHERE</literal>
clause contains constants (or externally supplied parameters).
For example, a comparison against a non-immutable function such as
<function>CURRENT_TIMESTAMP</function> cannot be optimized, since the
planner cannot know which child table the function's value might fall
into at run time.
</para>
</listitem>
<listitem>
<para>
Keep the partitioning constraints simple, else the planner may not be
able to prove that child tables might not need to be visited. Use simple
equality conditions for list partitioning, or simple
range tests for range partitioning, as illustrated in the preceding
examples. A good rule of thumb is that partitioning constraints should
contain only comparisons of the partitioning column(s) to constants
using B-tree-indexable operators, because only B-tree-indexable
column(s) are allowed in the partition key.
</para>
</listitem>
<listitem>
<para>
All constraints on all children of the parent table are examined
during constraint exclusion, so large numbers of children are likely
to increase query planning time considerably. So the legacy
inheritance based partitioning will work well with up to perhaps a
hundred child tables; don't try to use many thousands of children.
</para>
</listitem>
</itemizedlist>
</para>
</sect2>
<sect2 id="ddl-partitioning-declarative-best-practices">
<title>Best Practices for Declarative Partitioning</title>
<para>
The choice of how to partition a table should be made carefully, as the
performance of query planning and execution can be negatively affected by
poor design.
</para>
<para>
One of the most critical design decisions will be the column or columns
by which you partition your data. Often the best choice will be to
partition by the column or set of columns which most commonly appear in
<literal>WHERE</literal> clauses of queries being executed on the
partitioned table. <literal>WHERE</literal> clauses that are compatible
with the partition bound constraints can be used to prune unneeded
partitions. However, you may be forced into making other decisions by
requirements for the <literal>PRIMARY KEY</literal> or a
<literal>UNIQUE</literal> constraint. Removal of unwanted data is also a
factor to consider when planning your partitioning strategy. An entire
partition can be detached fairly quickly, so it may be beneficial to
design the partition strategy in such a way that all data to be removed
at once is located in a single partition.
</para>
<para>
Choosing the target number of partitions that the table should be divided
into is also a critical decision to make. Not having enough partitions
may mean that indexes remain too large and that data locality remains poor
which could result in low cache hit ratios. However, dividing the table
into too many partitions can also cause issues. Too many partitions can
mean longer query planning times and higher memory consumption during both
query planning and execution, as further described below.
When choosing how to partition your table,
it's also important to consider what changes may occur in the future. For
example, if you choose to have one partition per customer and you
currently have a small number of large customers, consider the
implications if in several years you instead find yourself with a large
number of small customers. In this case, it may be better to choose to
partition by <literal>HASH</literal> and choose a reasonable number of
partitions rather than trying to partition by <literal>LIST</literal> and
hoping that the number of customers does not increase beyond what it is
practical to partition the data by.
</para>
<para>
Sub-partitioning can be useful to further divide partitions that are
expected to become larger than other partitions.
Another option is to use range partitioning with multiple columns in
the partition key.
Either of these can easily lead to excessive numbers of partitions,
so restraint is advisable.
</para>
<para>
It is important to consider the overhead of partitioning during
query planning and execution. The query planner is generally able to
handle partition hierarchies with up to a few thousand partitions fairly
well, provided that typical queries allow the query planner to prune all
but a small number of partitions. Planning times become longer and memory
consumption becomes higher when more partitions remain after the planner
performs partition pruning. Another
reason to be concerned about having a large number of partitions is that
the server's memory consumption may grow significantly over
time, especially if many sessions touch large numbers of partitions.
That's because each partition requires its metadata to be loaded into the
local memory of each session that touches it.
</para>
<para>
With data warehouse type workloads, it can make sense to use a larger
number of partitions than with an <acronym>OLTP</acronym> type workload.
Generally, in data warehouses, query planning time is less of a concern as
the majority of processing time is spent during query execution. With
either of these two types of workload, it is important to make the right
decisions early, as re-partitioning large quantities of data can be
painfully slow. Simulations of the intended workload are often beneficial
for optimizing the partitioning strategy. Never just assume that more
partitions are better than fewer partitions, nor vice-versa.
</para>
</sect2>
</sect1>
<sect1 id="ddl-foreign-data">
<title>Foreign Data</title>
<indexterm>
<primary>foreign data</primary>
</indexterm>
<indexterm>
<primary>foreign table</primary>
</indexterm>
<indexterm>
<primary>user mapping</primary>
</indexterm>
<para>
<productname>PostgreSQL</productname> implements portions of the SQL/MED
specification, allowing you to access data that resides outside
PostgreSQL using regular SQL queries. Such data is referred to as
<firstterm>foreign data</firstterm>. (Note that this usage is not to be confused
with foreign keys, which are a type of constraint within the database.)
</para>
<para>
Foreign data is accessed with help from a
<firstterm>foreign data wrapper</firstterm>. A foreign data wrapper is a
library that can communicate with an external data source, hiding the
details of connecting to the data source and obtaining data from it.
There are some foreign data wrappers available as <filename>contrib</filename>
modules; see <xref linkend="contrib"/>. Other kinds of foreign data
wrappers might be found as third party products. If none of the existing
foreign data wrappers suit your needs, you can write your own; see <xref
linkend="fdwhandler"/>.
</para>
<para>
To access foreign data, you need to create a <firstterm>foreign server</firstterm>
object, which defines how to connect to a particular external data source
according to the set of options used by its supporting foreign data
wrapper. Then you need to create one or more <firstterm>foreign
tables</firstterm>, which define the structure of the remote data. A
foreign table can be used in queries just like a normal table, but a
foreign table has no storage in the PostgreSQL server. Whenever it is
used, <productname>PostgreSQL</productname> asks the foreign data wrapper
to fetch data from the external source, or transmit data to the external
source in the case of update commands.
</para>
<para>
Accessing remote data may require authenticating to the external
data source. This information can be provided by a
<firstterm>user mapping</firstterm>, which can provide additional data
such as user names and passwords based
on the current <productname>PostgreSQL</productname> role.
</para>
<para>
For additional information, see
<xref linkend="sql-createforeigndatawrapper"/>,
<xref linkend="sql-createserver"/>,
<xref linkend="sql-createusermapping"/>,
<xref linkend="sql-createforeigntable"/>, and
<xref linkend="sql-importforeignschema"/>.
</para>
</sect1>
<sect1 id="ddl-others">
<title>Other Database Objects</title>
<para>
Tables are the central objects in a relational database structure,
because they hold your data. But they are not the only objects
that exist in a database. Many other kinds of objects can be
created to make the use and management of the data more efficient
or convenient. They are not discussed in this chapter, but we give
you a list here so that you are aware of what is possible:
</para>
<itemizedlist>
<listitem>
<para>
Views
</para>
</listitem>
<listitem>
<para>
Functions, procedures, and operators
</para>
</listitem>
<listitem>
<para>
Data types and domains
</para>
</listitem>
<listitem>
<para>
Triggers and rewrite rules
</para>
</listitem>
</itemizedlist>
<para>
Detailed information on
these topics appears in <xref linkend="server-programming"/>.
</para>
</sect1>
<sect1 id="ddl-depend">
<title>Dependency Tracking</title>
<indexterm zone="ddl-depend">
<primary>CASCADE</primary>
<secondary sortas="DROP">with DROP</secondary>
</indexterm>
<indexterm zone="ddl-depend">
<primary>RESTRICT</primary>
<secondary sortas="DROP">with DROP</secondary>
</indexterm>
<para>
When you create complex database structures involving many tables
with foreign key constraints, views, triggers, functions, etc. you
implicitly create a net of dependencies between the objects.
For instance, a table with a foreign key constraint depends on the
table it references.
</para>
<para>
To ensure the integrity of the entire database structure,
<productname>PostgreSQL</productname> makes sure that you cannot
drop objects that other objects still depend on. For example,
attempting to drop the products table we considered in <xref
linkend="ddl-constraints-fk"/>, with the orders table depending on
it, would result in an error message like this:
<screen>
DROP TABLE products;
ERROR: cannot drop table products because other objects depend on it
DETAIL: constraint orders_product_no_fkey on table orders depends on table products
HINT: Use DROP ... CASCADE to drop the dependent objects too.
</screen>
The error message contains a useful hint: if you do not want to
bother deleting all the dependent objects individually, you can run:
<screen>
DROP TABLE products CASCADE;
</screen>
and all the dependent objects will be removed, as will any objects
that depend on them, recursively. In this case, it doesn't remove
the orders table, it only removes the foreign key constraint.
It stops there because nothing depends on the foreign key constraint.
(If you want to check what <command>DROP ... CASCADE</command> will do,
run <command>DROP</command> without <literal>CASCADE</literal> and read the
<literal>DETAIL</literal> output.)
</para>
<para>
Almost all <command>DROP</command> commands in <productname>PostgreSQL</productname> support
specifying <literal>CASCADE</literal>. Of course, the nature of
the possible dependencies varies with the type of the object. You
can also write <literal>RESTRICT</literal> instead of
<literal>CASCADE</literal> to get the default behavior, which is to
prevent dropping objects that any other objects depend on.
</para>
<note>
<para>
According to the SQL standard, specifying either
<literal>RESTRICT</literal> or <literal>CASCADE</literal> is
required in a <command>DROP</command> command. No database system actually
enforces that rule, but whether the default behavior
is <literal>RESTRICT</literal> or <literal>CASCADE</literal> varies
across systems.
</para>
</note>
<para>
If a <command>DROP</command> command lists multiple
objects, <literal>CASCADE</literal> is only required when there are
dependencies outside the specified group. For example, when saying
<literal>DROP TABLE tab1, tab2</literal> the existence of a foreign
key referencing <literal>tab1</literal> from <literal>tab2</literal> would not mean
that <literal>CASCADE</literal> is needed to succeed.
</para>
<para>
For user-defined functions, <productname>PostgreSQL</productname> tracks
dependencies associated with a function's externally-visible properties,
such as its argument and result types, but <emphasis>not</emphasis> dependencies
that could only be known by examining the function body. As an example,
consider this situation:
<programlisting>
CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow',
'green', 'blue', 'purple');
CREATE TABLE my_colors (color rainbow, note text);
CREATE FUNCTION get_color_note (rainbow) RETURNS text AS
'SELECT note FROM my_colors WHERE color = $1'
LANGUAGE SQL;
</programlisting>
(See <xref linkend="xfunc-sql"/> for an explanation of SQL-language
functions.) <productname>PostgreSQL</productname> will be aware that
the <function>get_color_note</function> function depends on the <type>rainbow</type>
type: dropping the type would force dropping the function, because its
argument type would no longer be defined. But <productname>PostgreSQL</productname>
will not consider <function>get_color_note</function> to depend on
the <structname>my_colors</structname> table, and so will not drop the function if
the table is dropped. While there are disadvantages to this approach,
there are also benefits. The function is still valid in some sense if the
table is missing, though executing it would cause an error; creating a new
table of the same name would allow the function to work again.
</para>
</sect1>
</chapter>
|