~vcs-imports/mammoth-replicator/trunk

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
<!--
$PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.57.4.1 2005-01-22 23:05:47 momjian Exp $
-->

<chapter id="plpgsql"> 
  <title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>

 <indexterm zone="plpgsql">
  <primary>PL/pgSQL</primary>
 </indexterm>

 <para>
  <application>PL/pgSQL</application> is a loadable procedural
  language for the <productname>PostgreSQL</productname> database
  system.  The design goals of <application>PL/pgSQL</> were to create
  a loadable procedural language that

    <itemizedlist>
     <listitem>
      <para>
       can be used to create functions and trigger procedures,
      </para>
     </listitem>
     <listitem>
      <para>
       adds control structures to the <acronym>SQL</acronym> language,
      </para>
     </listitem>
     <listitem>
      <para>
       can perform complex computations,
      </para>
     </listitem>
     <listitem>
      <para>
       inherits all user-defined types, functions, and operators,
      </para>
     </listitem>
     <listitem>
      <para>
       can be defined to be trusted by the server,
      </para>
     </listitem>
     <listitem>
      <para>
       is easy to use.
      </para>
     </listitem>
    </itemizedlist>
   </para>

   <para>
    Except for input/output conversion and calculation functions
    for user-defined types, anything that can be defined in C language
    functions can also be done with <application>PL/pgSQL</application>.
    For example, it is possible to
    create complex conditional computation functions and later use
    them to define operators or use them in index expressions.
   </para>

  <sect1 id="plpgsql-overview">
   <title>Overview</title>

   <para>
    The <application>PL/pgSQL</> call handler parses the function's source text and
    produces an internal binary instruction tree the first time the
    function is called (within each session).  The instruction tree
    fully translates the 
    <application>PL/pgSQL</> statement structure, but individual
    <acronym>SQL</acronym> expressions and <acronym>SQL</acronym> commands
    used in the function are not translated immediately.
   </para>

   <para>
    As each expression and <acronym>SQL</acronym> command is first
    used in the function, the <application>PL/pgSQL</> interpreter
    creates a prepared execution plan (using the
    <acronym>SPI</acronym> manager's <function>SPI_prepare</function>
    and <function>SPI_saveplan</function>
    functions).<indexterm><primary>preparing a query</><secondary>in
    PL/pgSQL</></> Subsequent visits to that expression or command
    reuse the prepared plan.  Thus, a function with conditional code
    that contains many statements for which execution plans might be
    required will only prepare and save those plans that are really
    used during the lifetime of the database connection.  This can
    substantially reduce the total amount of time required to parse,
    and generate execution plans for the statements in a
    <application>PL/pgSQL</> function. A disadvantage is that errors
    in a specific expression or command may not be detected until that
    part of the function is reached in execution.
   </para>

   <para>
    Once <application>PL/pgSQL</> has made an execution plan for a particular
    command in a function, it will reuse that plan for the life of the
    database connection.  This is usually a win for performance, but it
    can cause some problems if you dynamically
    alter your database schema. For example:

<programlisting>
CREATE FUNCTION populate() RETURNS integer AS $$
DECLARE
    -- declarations
BEGIN
    PERFORM my_function();
END;
$$ LANGUAGE plpgsql;
</programlisting>

    If you execute the above function, it will reference the OID for
    <function>my_function()</function> in the execution plan produced for
    the <command>PERFORM</command> statement. Later, if you
    drop and recreate <function>my_function()</function>, then
    <function>populate()</function> will not be able to find
    <function>my_function()</function> anymore. You would then have to
    recreate <function>populate()</function>, or at least start a new
    database session so that it will be compiled afresh. Another way
    to avoid this problem is to use <command>CREATE OR REPLACE
    FUNCTION</command> when updating the definition of
    <function>my_function</function> (when a function is
    <quote>replaced</quote>, its OID is not changed).
   </para>

   <para>
    Because <application>PL/pgSQL</application> saves execution plans
        in this way, SQL commands that appear directly in a
        <application>PL/pgSQL</application> function must refer to the
        same tables and columns on every execution; that is, you cannot use
        a parameter as the name of a table or column in an SQL command.  To get
        around this restriction, you can construct dynamic commands using
        the <application>PL/pgSQL</application> <command>EXECUTE</command>
        statement &mdash; at the price of constructing a new execution plan on
        every execution.
   </para>

   <note>
        <para>
         The <application>PL/pgSQL</application>
         <command>EXECUTE</command> statement is not related to the
         <xref linkend="sql-execute" endterm="sql-execute-title"> SQL
         statement supported by the
         <productname>PostgreSQL</productname> server. The server's
         <command>EXECUTE</command> statement cannot be used within
         <application>PL/pgSQL</> functions (and is not needed).
        </para>
   </note>

  <sect2 id="plpgsql-advantages">
   <title>Advantages of Using <application>PL/pgSQL</application></title>

    <para>
     <acronym>SQL</acronym> is the language <productname>PostgreSQL</>
     and most other relational databases use as query language. It's
     portable and easy to learn. But every <acronym>SQL</acronym>
     statement must be executed individually by the database server.
    </para>

    <para>
     That means that your client application must send each query to
     the database server, wait for it to be processed, receive the
     results, do some computation, then send other queries to the
     server. All this incurs interprocess communication and may also
     incur network overhead if your client is on a different machine
     than the database server.
    </para>

    <para>
     With <application>PL/pgSQL</application> you can group a block of computation and a
     series of queries <emphasis>inside</emphasis> the
     database server, thus having the power of a procedural
     language and the ease of use of SQL, but saving lots of
     time because you don't have the whole client/server
     communication overhead. This can make for a
     considerable performance increase.
    </para>

    <para>
     Also, with <application>PL/pgSQL</application> you can use all
     the data types, operators and functions of SQL.
    </para>
  </sect2>

  <sect2 id="plpgsql-args-results">
   <title>Supported Argument and Result Data Types</title>

    <para>
     Functions written in <application>PL/pgSQL</application> can accept
     as arguments any scalar or array data type supported by the server,
     and they can return a result of any of these types.  They can also
     accept or return any composite type (row type) specified by name.
     It is also possible to declare a <application>PL/pgSQL</application>
     function as returning <type>record</>, which means that the result
     is a row type whose columns are determined by specification in the
     calling query, as discussed in <xref linkend="queries-tablefunctions">.
    </para>

    <para>
     <application>PL/pgSQL</> functions may also be declared to accept
     and return the polymorphic types
     <type>anyelement</type> and <type>anyarray</type>.  The actual
     data types handled by a polymorphic function can vary from call to
     call, as discussed in <xref linkend="extend-types-polymorphic">.
     An example is shown in <xref linkend="plpgsql-declaration-aliases">.
    </para>

    <para>
     <application>PL/pgSQL</> functions can also be declared to return
     a <quote>set</>, or table, of any data type they can return a single
     instance of.  Such a function generates its output by executing
     <literal>RETURN NEXT</> for each desired element of the result set.
    </para>

    <para>
     Finally, a <application>PL/pgSQL</> function may be declared to return
     <type>void</> if it has no useful return value.
    </para>

    <para>
     <application>PL/pgSQL</> does not currently have full support for
     domain types: it treats a domain the same as the underlying scalar
     type.  This means that constraints associated with the domain will
     not be enforced.  This is not an issue for function arguments, but
     it is a hazard if you declare a <application>PL/pgSQL</> function
     as returning a domain type.
    </para>
  </sect2>
 </sect1>

 <sect1 id="plpgsql-development-tips">
  <title>Tips for Developing in <application>PL/pgSQL</application></title>

   <para>
    One good way to develop in
    <application>PL/pgSQL</> is to use the text editor of your
    choice to create your functions, and in another window, use
    <application>psql</application> to load and test those functions.
    If you are doing it this way, it
    is a good idea to write the function using <command>CREATE OR
    REPLACE FUNCTION</>. That way you can just reload the file to update
    the function definition.  For example:
<programlisting>
CREATE OR REPLACE FUNCTION testfunc(integer) RETURNS integer AS $$
          ....
$$ LANGUAGE plpgsql;
</programlisting>
   </para>

   <para>
    While running <application>psql</application>, you can load or reload such
    a function definition file with
<programlisting>
\i filename.sql
</programlisting>
    and then immediately issue SQL commands to test the function.
   </para>

   <para>
    Another good way to develop in <application>PL/pgSQL</> is with a
    GUI database access tool that facilitates development in a
    procedural language. One example of such as a tool is
    <application>PgAccess</>, although others exist. These tools often
    provide convenient features such as escaping single quotes and
    making it easier to recreate and debug functions.
   </para>

  <sect2 id="plpgsql-quote-tips">
   <title>Handling of Quotation Marks</title>

   <para>
    The code of a <application>PL/pgSQL</> function is specified in
    <command>CREATE FUNCTION</command> as a string literal.  If you
    write the string literal in the ordinary way with surrounding
    single quotes, then any single quotes inside the function body
    must be doubled; likewise any backslashes must be doubled.
    Doubling quotes is at best tedious, and in more complicated cases
    the code can become downright incomprehensible, because you can
    easily find yourself needing half a dozen or more adjacent quote marks.
    It's recommended that you instead write the function body as a
    <quote>dollar-quoted</> string literal (see <xref
    linkend="sql-syntax-dollar-quoting">).  In the dollar-quoting
    approach, you never double any quote marks, but instead take care to
    choose a different dollar-quoting delimiter for each level of
    nesting you need.  For example, you might write the <command>CREATE
    FUNCTION</command> command as
<programlisting>
CREATE OR REPLACE FUNCTION testfunc(integer) RETURNS integer AS $PROC$
          ....
$PROC$ LANGUAGE plpgsql;
</programlisting>
    Within this, you might use quote marks for simple literal strings in
    SQL commands and <literal>$$</> to delimit fragments of SQL commands
    that you are assembling as strings.  If you need to quote text that
    includes <literal>$$</>, you could use <literal>$Q$</>, and so on.
   </para>

   <para>
    The following chart shows what you have to do when writing quote
    marks without dollar quoting.  It may be useful when translating
    pre-dollar quoting code into something more comprehensible.
  </para>

  <variablelist>
   <varlistentry>
    <term>1 quotation mark</term>
    <listitem>
     <para>
      To begin and end the function body, for example:
<programlisting>
CREATE FUNCTION foo() RETURNS integer AS '
          ....
' LANGUAGE plpgsql;
</programlisting>
      Anywhere within a single-quoted function body, quote marks
      <emphasis>must</> appear in pairs.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term>2 quotation marks</term>
    <listitem>
     <para>
      For string literals inside the function body, for example:
<programlisting>
a_output := ''Blah'';
SELECT * FROM users WHERE f_name=''foobar'';
</programlisting>
      In the dollar-quoting approach, you'd just write
<programlisting>
a_output := 'Blah';
SELECT * FROM users WHERE f_name='foobar';
</programlisting>
      which is exactly what the <application>PL/pgSQL</> parser would see
      in either case.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term>4 quotation marks</term>
    <listitem>
     <para>
      When you need a single quotation mark in a string constant inside the
      function body, for example:
<programlisting>
a_output := a_output || '' AND name LIKE ''''foobar'''' AND xyz''
</programlisting>
      The value actually appended to <literal>a_output</literal> would be:
      <literal> AND name LIKE 'foobar' AND xyz</literal>.
     </para>
     <para>
      In the dollar-quoting approach, you'd write
<programlisting>
a_output := a_output || $$ AND name LIKE 'foobar' AND xyz$$
</programlisting>
      being careful that any dollar-quote delimiters around this are not
      just <literal>$$</>.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term>6 quotation marks</term>
    <listitem>
     <para>
      When a single quotation mark in a string inside the function body is
      adjacent to the end of that string constant, for example:
<programlisting>
a_output := a_output || '' AND name LIKE ''''foobar''''''
</programlisting>
      The value appended to <literal>a_output</literal> would then be:
      <literal> AND name LIKE 'foobar'</literal>.
     </para>
     <para>
      In the dollar-quoting approach, this becomes
<programlisting>
a_output := a_output || $$ AND name LIKE 'foobar'$$
</programlisting>
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term>10 quotation marks</term>
    <listitem>
     <para>
      When you want two single quotation marks in a string constant (which
      accounts for 8 quotation marks) and this is adjacent to the end of that
      string constant (2 more).  You will probably only need that if
      you are writing a function that generates other functions, as in
      <xref linkend="plpgsql-porting-ex2">.
      For example:
<programlisting>
a_output := a_output || '' if v_'' || 
    referrer_keys.kind || '' like '''''''''' 
    || referrer_keys.key_string || '''''''''' 
    then return ''''''  || referrer_keys.referrer_type 
    || ''''''; end if;''; 
</programlisting>
      The value of <literal>a_output</literal> would then be:
<programlisting>
if v_... like ''...'' then return ''...''; end if;
</programlisting>
     </para>
     <para>
      In the dollar-quoting approach, this becomes
<programlisting>
a_output := a_output || $$ if v_$$ || referrer_keys.kind || $$ like '$$
    || referrer_keys.key_string || $$'
    then return '$$  || referrer_keys.referrer_type 
    || $$'; end if;$$; 
</programlisting>
      where we assume we only need to put single quote marks into
      <literal>a_output</literal>, because it will be re-quoted before use.
     </para>
    </listitem>
   </varlistentry>
  </variablelist>

   <para>
    A variant approach is to escape quotation marks in the function body
    with a backslash rather than by doubling them.  With this method
    you'll find yourself writing things like <literal>\'\'</> instead
    of <literal>''''</>.  Some find this easier to keep track of, some
    do not.
   </para>
  </sect2>
 </sect1>

 <sect1 id="plpgsql-structure">
  <title>Structure of <application>PL/pgSQL</application></title>

  <para>
   <application>PL/pgSQL</application> is a block-structured language.
   The complete text of a function definition must be a
   <firstterm>block</>. A block is defined as:

<synopsis>
<optional> &lt;&lt;<replaceable>label</replaceable>&gt;&gt; </optional>
<optional> DECLARE
    <replaceable>declarations</replaceable> </optional>
BEGIN
    <replaceable>statements</replaceable>
END;
</synopsis>
    </para>

    <para>
     Each declaration and each statement within a block is terminated
     by a semicolon.  A block that appears within another block must
     have a semicolon after <literal>END</literal>, as shown above;
     however the final <literal>END</literal> that
     concludes a function body does not require a semicolon.
    </para>

    <para>
     All key words and identifiers can be written in mixed upper and
     lower case.  Identifiers are implicitly converted to lowercase
     unless double-quoted.
    </para>

    <para>
     There are two types of comments in <application>PL/pgSQL</>. A double
     dash (<literal>--</literal>) starts a comment that extends to the end of
     the line. A <literal>/*</literal> starts a block comment that extends to
     the next occurrence of <literal>*/</literal>.  Block comments cannot be
     nested, but double dash comments can be enclosed into a block comment and
     a double dash can hide the block comment delimiters <literal>/*</literal>
     and <literal>*/</literal>.
    </para>

    <para>
     Any statement in the statement section of a block
     can be a <firstterm>subblock</>.  Subblocks can be used for
     logical grouping or to localize variables to a small group
     of statements.
    </para>

    <para>
     The variables declared in the declarations section preceding a
     block are initialized to their default values every time the
     block is entered, not only once per function call. For example:
<programlisting>
CREATE FUNCTION somefunc() RETURNS integer AS $$
DECLARE
    quantity integer := 30;
BEGIN
    RAISE NOTICE 'Quantity here is %', quantity;  -- Quantity here is 30
    quantity := 50;
    --
    -- Create a subblock
    --
    DECLARE
        quantity integer := 80;
    BEGIN
        RAISE NOTICE 'Quantity here is %', quantity;  -- Quantity here is 80
    END;

    RAISE NOTICE 'Quantity here is %', quantity;  -- Quantity here is 50

    RETURN quantity;
END;
$$ LANGUAGE plpgsql;
</programlisting>
    </para>

    <para>
     It is important not to confuse the use of
     <command>BEGIN</>/<command>END</> for grouping statements in
     <application>PL/pgSQL</> with the database commands for transaction
     control.  <application>PL/pgSQL</>'s <command>BEGIN</>/<command>END</>
     are only for grouping; they do not start or end a transaction.
     Functions and trigger procedures are always executed within a transaction
     established by an outer query &mdash; they cannot start or commit that
     transaction, since there would be no context for them to execute in.
     However, a block containing an <literal>EXCEPTION</> clause effectively
     forms a subtransaction that can be rolled back without affecting the
     outer transaction.  For more about that see <xref
     linkend="plpgsql-error-trapping">.
    </para>
  </sect1>

  <sect1 id="plpgsql-declarations">
    <title>Declarations</title>

    <para>
     All variables used in a block must be declared in the
     declarations section of the block. 
     (The only exception is that the loop variable of a <literal>FOR</> loop
     iterating over a range of integer values is automatically declared as an
     integer variable.)
    </para>

    <para>
     <application>PL/pgSQL</> variables can have any SQL data type, such as
     <type>integer</type>, <type>varchar</type>, and
     <type>char</type>.
    </para>

    <para>
     Here are some examples of variable declarations:
<programlisting>
user_id integer;
quantity numeric(5);
url varchar;
myrow tablename%ROWTYPE;
myfield tablename.columnname%TYPE;
arow RECORD;
</programlisting>
    </para>

    <para>
     The general syntax of a variable declaration is:
<synopsis>
<replaceable>name</replaceable> <optional> CONSTANT </optional> <replaceable>type</replaceable> <optional> NOT NULL </optional> <optional> { DEFAULT | := } <replaceable>expression</replaceable> </optional>;
</synopsis>
      The <literal>DEFAULT</> clause, if given, specifies the initial value assigned
      to the variable when the block is entered.  If the <literal>DEFAULT</> clause
      is not given then the variable is initialized to the
      <acronym>SQL</acronym> null value. 
      The <literal>CONSTANT</> option prevents the variable from being assigned to,
      so that its value remains constant for the duration of the block.
      If <literal>NOT NULL</>
      is specified, an assignment of a null value results in a run-time
      error. All variables declared as <literal>NOT NULL</>
      must have a nonnull default value specified.
     </para>

     <para>
      The default value is evaluated every time the block is entered. So,
      for example, assigning <literal>now()</literal> to a variable of type
      <type>timestamp</type> causes the variable to have the
      time of the current function call, not the time when the function was
      precompiled.
     </para>

     <para>
      Examples:
<programlisting>
quantity integer DEFAULT 32;
url varchar := 'http://mysite.com';
user_id CONSTANT integer := 10;
</programlisting>
     </para>

    <sect2 id="plpgsql-declaration-aliases">
     <title>Aliases for Function Parameters</title>

     <para>
      Parameters passed to functions are named with the identifiers
      <literal>$1</literal>, <literal>$2</literal>,
      etc.  Optionally, aliases can be declared for
      <literal>$<replaceable>n</replaceable></literal>
      parameter names for increased readability.  Either the alias or the
      numeric identifier can then be used to refer to the parameter value.
     </para>

     <para>
      There are two ways to create an alias.  The preferred way is to give a
      name to the parameter in the <command>CREATE FUNCTION</command> command,
      for example:
<programlisting>
CREATE FUNCTION sales_tax(subtotal real) RETURNS real AS $$
BEGIN
    RETURN subtotal * 0.06;
END;
$$ LANGUAGE plpgsql;
</programlisting>
      The other way, which was the only way available before
      <productname>PostgreSQL</productname> 8.0, is to explicitly
      declare an alias, using the declaration syntax

<synopsis>
<replaceable>name</replaceable> ALIAS FOR $<replaceable>n</replaceable>;
</synopsis>

      The same example in this style looks like
<programlisting>
CREATE FUNCTION sales_tax(real) RETURNS real AS $$
DECLARE
    subtotal ALIAS FOR $1;
BEGIN
    RETURN subtotal * 0.06;
END;
$$ LANGUAGE plpgsql;
</programlisting>
      Some more examples:
<programlisting>
CREATE FUNCTION instr(varchar, integer) RETURNS integer AS $$
DECLARE
    v_string ALIAS FOR $1;
    index ALIAS FOR $2;
BEGIN
    -- some computations here
END;
$$ LANGUAGE plpgsql;


CREATE FUNCTION concat_selected_fields(in_t tablename) RETURNS text AS $$
BEGIN
    RETURN in_t.f1 || in_t.f3 || in_t.f5 || in_t.f7;
END;
$$ LANGUAGE plpgsql;
</programlisting>
     </para>

     <para>
      When the return type of a <application>PL/pgSQL</application>
      function is declared as a polymorphic type (<type>anyelement</type>
      or <type>anyarray</type>), a special parameter <literal>$0</literal>
      is created.  Its data type is the actual return type of the function,
      as deduced from the actual input types (see <xref
      linkend="extend-types-polymorphic">).
      This allows the function to access its actual return type
      as shown in <xref linkend="plpgsql-declaration-type">.
      <literal>$0</literal> is initialized to null and can be modified by
      the function, so it can be used to hold the return value if desired,
      though that is not required.  <literal>$0</literal> can also be
      given an alias.  For example, this function works on any data type
      that has a <literal>+</> operator:
<programlisting>
CREATE FUNCTION add_three_values(v1 anyelement, v2 anyelement, v3 anyelement)
RETURNS anyelement AS $$
DECLARE
    result ALIAS FOR $0;
BEGIN
    result := v1 + v2 + v3;
    RETURN result;
END;
$$ LANGUAGE plpgsql;
</programlisting>
     </para>
    </sect2>

  <sect2 id="plpgsql-declaration-type">
   <title>Copying Types</title>

<synopsis>
<replaceable>variable</replaceable>%TYPE
</synopsis>

   <para>
    <literal>%TYPE</literal> provides the data type of a variable or
    table column. You can use this to declare variables that will hold
    database values. For example, let's say you have a column named
    <literal>user_id</literal> in your <literal>users</literal>
    table. To declare a variable with the same data type as
    <literal>users.user_id</> you write:
<programlisting>
user_id users.user_id%TYPE;
</programlisting>
   </para>

   <para>
    By using <literal>%TYPE</literal> you don't need to know the data
    type of the structure you are referencing, and most importantly,
    if the data type of the referenced item changes in the future (for
    instance: you change the type of <literal>user_id</>
    from <type>integer</type> to <type>real</type>), you may not need
    to change your function definition.
   </para>

   <para>
    <literal>%TYPE</literal> is particularly valuable in polymorphic
    functions, since the data types needed for internal variables may
    change from one call to the next.  Appropriate variables can be
    created by applying <literal>%TYPE</literal> to the function's
    arguments or result placeholders.
   </para>

  </sect2>

    <sect2 id="plpgsql-declaration-rowtypes">
     <title>Row Types</title>

<synopsis>
<replaceable>name</replaceable> <replaceable>table_name</replaceable><literal>%ROWTYPE</literal>;
<replaceable>name</replaceable> <replaceable>composite_type_name</replaceable>;
</synopsis>

   <para>
    A variable of a composite type is called a <firstterm>row</>
    variable (or <firstterm>row-type</> variable).  Such a variable
    can hold a whole row of a <command>SELECT</> or <command>FOR</>
    query result, so long as that query's column set matches the
    declared type of the variable.
    The individual fields of the row value
    are accessed using the usual dot notation, for example
    <literal>rowvar.field</literal>.
   </para>

   <para>
    A row variable can be declared to have the same type as the rows of
    an existing table or view, by using the
    <replaceable>table_name</replaceable><literal>%ROWTYPE</literal>
    notation; or it can be declared by giving a composite type's name.
    (Since every table has an associated composite type of the same name,
    it actually does not matter in <productname>PostgreSQL</> whether you
    write <literal>%ROWTYPE</literal> or not.  But the form with
    <literal>%ROWTYPE</literal> is more portable.)
   </para>

   <para>
    Parameters to a function can be
    composite types (complete table rows). In that case, the
    corresponding identifier <literal>$<replaceable>n</replaceable></> will be a row variable, and fields can
    be selected from it, for example <literal>$1.user_id</literal>.
   </para>

   <para>
    Only the user-defined columns of a table row are accessible in a
    row-type variable, not the OID or other system columns (because the
    row could be from a view).  The fields of the row type inherit the
    table's field size or precision for data types such as
    <type>char(<replaceable>n</>)</type>.
   </para>

   <para>
    Here is an example of using composite types:
<programlisting>
CREATE FUNCTION merge_fields(t_row tablename) RETURNS text AS $$
DECLARE
    t2_row table2name%ROWTYPE;
BEGIN
    SELECT * INTO t2_row FROM table2name WHERE ... ;
    RETURN t_row.f1 || t2_row.f3 || t_row.f5 || t2_row.f7;
END;
$$ LANGUAGE plpgsql;

SELECT merge_fields(t.*) FROM tablename t WHERE ... ;
</programlisting>
   </para>
  </sect2>

  <sect2 id="plpgsql-declaration-records">
   <title>Record Types</title>

<synopsis>
<replaceable>name</replaceable> RECORD;
</synopsis>

   <para>
    Record variables are similar to row-type variables, but they have no
    predefined structure.  They take on the actual row structure of the
    row they are assigned during a <command>SELECT</> or <command>FOR</> command.  The substructure
    of a record variable can change each time it is assigned to.
    A consequence of this is that until a record variable is first assigned
    to, it has no substructure, and any attempt to access a
    field in it will draw a run-time error.
   </para>

   <para>
    Note that <literal>RECORD</> is not a true data type, only a placeholder.
    One should also realize that when a <application>PL/pgSQL</application>
    function is declared to return type <type>record</>, this is not quite the
    same concept as a record variable, even though such a function may well
    use a record variable to hold its result.  In both cases the actual row
    structure is unknown when the function is written, but for a function
    returning <type>record</> the actual structure is determined when the
    calling query is parsed, whereas a record variable can change its row
    structure on-the-fly.
   </para>
  </sect2>

  <sect2 id="plpgsql-declaration-renaming-vars">
   <title><literal>RENAME</></title>

<synopsis>
RENAME <replaceable>oldname</replaceable> TO <replaceable>newname</replaceable>;
</synopsis>

   <para>
    Using the <literal>RENAME</literal> declaration you can change the
    name of a variable, record or row. This is primarily useful if
    <varname>NEW</varname> or <varname>OLD</varname> should be
    referenced by another name inside a trigger procedure.  See also
    <literal>ALIAS</literal>.
   </para>

   <para>
    Examples:
<programlisting>
RENAME id TO user_id;
RENAME this_var TO that_var;
</programlisting>
   </para>

    <note>
     <para>
      <literal>RENAME</literal> appears to be broken as of
      <productname>PostgreSQL</> 7.3.  Fixing this is of low priority,
      since <literal>ALIAS</literal> covers most of the practical uses
      of <literal>RENAME</literal>.
     </para>
    </note>
   </sect2>
  </sect1>

  <sect1 id="plpgsql-expressions">
  <title>Expressions</title>

    <para>
     All expressions used in <application>PL/pgSQL</application>
     statements are processed using the server's regular
     <acronym>SQL</acronym> executor.  In effect, a query like
<synopsis>
SELECT <replaceable>expression</replaceable>
</synopsis>
     is executed using the <acronym>SPI</acronym> manager. Before evaluation,
     occurrences of <application>PL/pgSQL</application> variable
     identifiers are replaced by parameters, and the actual values from
     the variables are passed to the executor in the parameter array.
     This allows the query plan for the <command>SELECT</command> to
     be prepared just once and then reused for subsequent
     evaluations.
    </para>

    <para>
     The evaluation done by the <productname>PostgreSQL</productname>
     main parser has some side
     effects on the interpretation of constant values. In detail there
     is a difference between what these two functions do:

<programlisting>
CREATE FUNCTION logfunc1(logtxt text) RETURNS timestamp AS $$
    BEGIN
        INSERT INTO logtable VALUES (logtxt, 'now');
        RETURN 'now';
    END;
$$ LANGUAGE plpgsql;
</programlisting>

     and

<programlisting>
CREATE FUNCTION logfunc2(logtxt text) RETURNS timestamp AS $$
    DECLARE
        curtime timestamp;
    BEGIN
        curtime := 'now';
        INSERT INTO logtable VALUES (logtxt, curtime);
        RETURN curtime;
    END;
$$ LANGUAGE plpgsql;
</programlisting>
    </para>

    <para>
     In the case of <function>logfunc1</function>, the 
     <productname>PostgreSQL</productname> main parser knows when 
     preparing the plan for the <command>INSERT</command>, that the string 
     <literal>'now'</literal> should be interpreted as 
     <type>timestamp</type> because the target column of <classname>logtable</classname>
     is of that type. Thus, it will make a constant from it at this
     time and this constant value is then used in all invocations of 
     <function>logfunc1</function> during the lifetime of the
     session. Needless to say that this isn't what the
     programmer wanted.
    </para>

    <para>
     In the case of <function>logfunc2</function>, the 
     <productname>PostgreSQL</productname> main parser does not know
     what type <literal>'now'</literal> should become and therefore 
     it returns a data value of type <type>text</type> containing the string 
     <literal>now</literal>. During the ensuing assignment
     to the local variable <varname>curtime</varname>, the
     <application>PL/pgSQL</application> interpreter casts this
     string to the <type>timestamp</type> type by calling the
     <function>text_out</function> and <function>timestamp_in</function>
     functions for the conversion.  So, the computed time stamp is updated
     on each execution as the programmer expects.
    </para>

    <para>
     The mutable nature of record variables presents a problem in this
     connection.  When fields of a record variable are used in
     expressions or statements, the data types of the fields must not
     change between calls of one and the same expression, since the
     expression will be planned using the data type that is present
     when the expression is first reached.  Keep this in mind when
     writing trigger procedures that handle events for more than one
     table.  (<command>EXECUTE</command> can be used to get around
     this problem when necessary.)
    </para>
  </sect1>

  <sect1 id="plpgsql-statements">
  <title>Basic Statements</title>

   <para>
    In this section and the following ones, we describe all the statement
    types that are explicitly understood by
    <application>PL/pgSQL</application>.
    Anything not recognized as one of these statement types is presumed
    to be an SQL command and is sent to the main database engine to execute
    (after substitution of any <application>PL/pgSQL</application> variables
    used in the statement).  Thus,
    for example, the SQL commands <command>INSERT</>, <command>UPDATE</>, and
    <command>DELETE</> may be considered to be statements of
    <application>PL/pgSQL</application>, but they are not specifically
    listed here.
   </para>

   <sect2 id="plpgsql-statements-assignment">
    <title>Assignment</title>

    <para>
     An assignment of a value to a variable or row/record field is
     written as:
<synopsis>
<replaceable>identifier</replaceable> := <replaceable>expression</replaceable>;
</synopsis>
     As explained above, the expression in such a statement is evaluated
     by means of an SQL <command>SELECT</> command sent to the main
     database engine.  The expression must yield a single value.
    </para>

    <para>
     If the expression's result data type doesn't match the variable's
     data type, or the variable has a specific size/precision
     (like <type>char(20)</type>), the result value will be implicitly
     converted by the <application>PL/pgSQL</application> interpreter using
     the result type's output-function and 
     the variable type's input-function. Note that this could potentially
     result in run-time errors generated by the input function, if the
     string form of the result value is not acceptable to the input function.
    </para>

    <para>
     Examples:
<programlisting>
user_id := 20;
tax := subtotal * 0.06;
</programlisting>
    </para>
   </sect2>

   <sect2 id="plpgsql-select-into">
    <title><command>SELECT INTO</command></title>

    <indexterm zone="plpgsql-select-into">
     <primary>SELECT INTO</primary>
     <secondary>in PL/pgSQL</secondary>
    </indexterm>

    <para>
     The result of a <command>SELECT</command> command yielding multiple columns (but
     only one row) can be assigned to a record variable, row-type
     variable, or list of scalar variables.  This is done by:

<synopsis>
SELECT INTO <replaceable>target</replaceable> <replaceable>select_expressions</replaceable> FROM ...;
</synopsis>

     where <replaceable>target</replaceable> can be a record variable, a row
     variable, or a comma-separated list of simple variables and
     record/row fields.  The <replaceable>select_expressions</replaceable>
     and the remainder of the command are the same as in regular SQL.
    </para>

    <para>
     Note that this is quite different from
     <productname>PostgreSQL</>'s normal interpretation of
     <command>SELECT INTO</command>, where the <literal>INTO</> target
     is a newly created table.  If you want to create a table from a
     <command>SELECT</> result inside a
     <application>PL/pgSQL</application> function, use the syntax
     <command>CREATE TABLE ... AS SELECT</command>.
    </para>

    <para>
     If a row or a variable list is used as target, the selected values
     must exactly match the structure of the target, or a run-time error
     occurs.  When a record variable is the target, it automatically
     configures itself to the row type of the query result columns.
    </para>

    <para>
     Except for the <literal>INTO</> clause, the <command>SELECT</>
     statement is the same as a normal SQL <command>SELECT</> command
     and can use its full power.
    </para>

    <para>
     The <literal>INTO</> clause can appear almost anywhere in the
     <command>SELECT</command> statement.  Customarily it is written
     either just after <literal>SELECT</> as shown above, or
     just before <literal>FROM</> &mdash; that is, either just before
     or just after the list of <replaceable>select_expressions</replaceable>.
    </para>

    <para>
     If the query returns zero rows, null values are assigned to the
     target(s).  If the query returns multiple rows, the first
     row is assigned to the target(s) and the rest are discarded.
     (Note that <quote>the first row</> is not well-defined unless you've
     used <literal>ORDER BY</>.)
    </para>

    <para>
     You can check the special <literal>FOUND</literal> variable (see
     <xref linkend="plpgsql-statements-diagnostics">) after a
     <command>SELECT INTO</command> statement to determine whether the
     assignment was successful, that is, at least one row was was returned by
     the query. For example:

<programlisting>
SELECT INTO myrec * FROM emp WHERE empname = myname;
IF NOT FOUND THEN
    RAISE EXCEPTION 'employee % not found', myname;
END IF;
</programlisting>
    </para>

    <para>
     To test for whether a record/row result is null, you can use the
     <literal>IS NULL</literal> conditional.  There is, however, no
     way to tell whether any additional rows might have been
     discarded.  Here is an example that handles the case where no
     rows have been returned:
<programlisting>
DECLARE
    users_rec RECORD;
BEGIN
    SELECT INTO users_rec * FROM users WHERE user_id=3;

    IF users_rec.homepage IS NULL THEN
        -- user entered no homepage, return "http://"
        RETURN 'http://';
    END IF;
END;
</programlisting>
    </para>
   </sect2>

   <sect2 id="plpgsql-statements-perform">
    <title>Executing an Expression or Query With No Result</title>

    <para>
     Sometimes one wishes to evaluate an expression or query but
     discard the result (typically because one is calling a function
     that has useful side-effects but no useful result value).  To do
     this in <application>PL/pgSQL</application>, use the
     <command>PERFORM</command> statement:

<synopsis>
PERFORM <replaceable>query</replaceable>;
</synopsis>

     This executes <replaceable>query</replaceable> and discards the
     result.  Write the <replaceable>query</replaceable> the same
     way as you would in an SQL <command>SELECT</> command, but replace the
     initial keyword <command>SELECT</> with <command>PERFORM</command>.
     <application>PL/pgSQL</application> variables will be
     substituted into the query as usual.  Also, the special variable
     <literal>FOUND</literal> is set to true if the query produced at
     least one row or false if it produced no rows.
    </para>

    <note>
     <para>
      One might expect that <command>SELECT</command> with no
      <literal>INTO</> clause would accomplish this result, but at
      present the only accepted way to do it is
      <command>PERFORM</command>.
     </para>
    </note>

    <para>
     An example:
<programlisting>
PERFORM create_mv('cs_session_page_requests_mv', my_query);
</programlisting>
    </para>
   </sect2>

   <sect2 id="plpgsql-statements-null">
    <title>Doing Nothing At All</title>

    <para>
     Sometimes a placeholder statement that does nothing is useful.
     For example, it can indicate that one arm of an if/then/else
     chain is deliberately empty.  For this purpose, use the
     <command>NULL</command> statement:

<synopsis>
NULL;
</synopsis>
    </para>

    <para>
     For example, the following two fragments of code are equivalent:
<programlisting>
    BEGIN
        y := x / 0;
    EXCEPTION
        WHEN division_by_zero THEN
            NULL;  -- ignore the error
    END;
</programlisting>

<programlisting>
    BEGIN
        y := x / 0;
    EXCEPTION
        WHEN division_by_zero THEN  -- ignore the error
    END;
</programlisting>
     Which is preferable is a matter of taste.
    </para>

    <note>
     <para>
      In Oracle's PL/SQL, empty statement lists are not allowed, and so
      <command>NULL</> statements are <emphasis>required</> for situations
      such as this.  <application>PL/pgSQL</application> allows you to
      just write nothing, instead.
     </para>
    </note>

   </sect2>

   <sect2 id="plpgsql-statements-executing-dyn">
    <title>Executing Dynamic Commands</title>

    <para>
     Oftentimes you will want to generate dynamic commands inside your
     <application>PL/pgSQL</application> functions, that is, commands
     that will involve different tables or different data types each
     time they are executed.  <application>PL/pgSQL</application>'s
     normal attempts to cache plans for commands will not work in such
     scenarios.  To handle this sort of problem, the
     <command>EXECUTE</command> statement is provided:

<synopsis>
EXECUTE <replaceable class="command">command-string</replaceable>;
</synopsis>

     where <replaceable>command-string</replaceable> is an expression
     yielding a string (of type
     <type>text</type>) containing the command
     to be executed.  This string is fed literally to the SQL engine.
    </para>

    <para>
     Note in particular that no substitution of <application>PL/pgSQL</>
     variables is done on the command string.  The values of variables must
     be inserted in the command string as it is constructed.
    </para>

    <para>
     Unlike all other commands in <application>PL/pgSQL</>, a command
     run by an <command>EXECUTE</command> statement is not prepared
     and saved just once during the life of the session.  Instead, the
     command is prepared each time the statement is run. The command
     string can be dynamically created within the function to perform
     actions on different tables and columns.
    </para>

    <para>
     The results from <command>SELECT</command> commands are discarded
     by <command>EXECUTE</command>, and <command>SELECT INTO</command>
     is not currently supported within <command>EXECUTE</command>.
     So there is no way to extract a result from a dynamically-created
     <command>SELECT</command> using the plain <command>EXECUTE</command>
     command.  There are two other ways to do it, however: one is to use the
     <command>FOR-IN-EXECUTE</>
     loop form described in <xref linkend="plpgsql-records-iterating">,
     and the other is to use a cursor with <command>OPEN-FOR-EXECUTE</>, as
     described in <xref linkend="plpgsql-cursor-opening">.
    </para>

    <para>
     When working with dynamic commands you will often have to handle escaping
     of single quotes.  The recommended method for quoting fixed text in your
     function body is dollar quoting.  (If you have legacy code that does
     not use dollar quoting, please refer to the
     overview in <xref linkend="plpgsql-quote-tips">, which can save you
     some effort when translating said code to a more reasonable scheme.)
    </para>

    <para>
     Dynamic values that are to be inserted into the constructed
     query require special handling since they might themselves contain
     quote characters.
     An example (this assumes that you are using dollar quoting for the
     function as a whole, so the quote marks need not be doubled):
<programlisting>
EXECUTE 'UPDATE tbl SET '
        || quote_ident(colname)
        || ' = '
        || quote_literal(newvalue)
        || ' WHERE key = '
        || quote_literal(keyvalue);
</programlisting>
    </para>

    <para>
     This example shows use of the functions
     <function>quote_ident(<type>text</type>)</function> and
     <function>quote_literal(<type>text</type>)</function>.<indexterm><primary>quote_ident</><secondary>use
     in
     PL/pgSQL</></indexterm><indexterm><primary>quote_literal</><secondary>use
     in PL/pgSQL</></indexterm> For safety, variables containing column and
     table identifiers should be passed to function
     <function>quote_ident</function>.  Variables containing values
     that should be literal strings in the constructed command should
     be passed to <function>quote_literal</function>.  Both take the
     appropriate steps to return the input text enclosed in double or
     single quotes respectively, with any embedded special characters
     properly escaped.
    </para>

    <para>
     Note that dollar quoting is only useful for quoting fixed text.
     It would be a very bad idea to try to do the above example as
<programlisting>
EXECUTE 'UPDATE tbl SET '
        || quote_ident(colname)
        || ' = $$'
        || newvalue
        || '$$ WHERE key = '
        || quote_literal(keyvalue);
</programlisting>
     because it would break if the contents of <literal>newvalue</>
     happened to contain <literal>$$</>.  The same objection would
     apply to any other dollar-quoting delimiter you might pick.
     So, to safely quote text that is not known in advance, you
     <emphasis>must</> use <function>quote_literal</function>.
    </para>

    <para>
     A much larger example of a dynamic command and
     <command>EXECUTE</command> can be seen in <xref
     linkend="plpgsql-porting-ex2">, which builds and executes a
     <command>CREATE FUNCTION</> command to define a new function.
    </para>
   </sect2>

   <sect2 id="plpgsql-statements-diagnostics">
    <title>Obtaining the Result Status</title>

    <para>
     There are several ways to determine the effect of a command. The
     first method is to use the <command>GET DIAGNOSTICS</command>
     command, which has the form:

<synopsis>
GET DIAGNOSTICS <replaceable>variable</replaceable> = <replaceable>item</replaceable> <optional> , ... </optional> ;
</synopsis>

     This command allows retrieval of system status indicators.  Each
     <replaceable>item</replaceable> is a key word identifying a state
     value to be assigned to the specified variable (which should be
     of the right data type to receive it).  The currently available
     status items are <varname>ROW_COUNT</>, the number of rows
     processed by the last <acronym>SQL</acronym> command sent down to
     the <acronym>SQL</acronym> engine, and <varname>RESULT_OID</>,
     the OID of the last row inserted by the most recent
     <acronym>SQL</acronym> command.  Note that <varname>RESULT_OID</>
     is only useful after an <command>INSERT</command> command.
    </para>

    <para>
     An example:
<programlisting>
GET DIAGNOSTICS integer_var = ROW_COUNT;
</programlisting>
    </para>

    <para>
     The second method to determine the effects of a command is to check the
     special variable named <literal>FOUND</literal>, which is of
     type <type>boolean</type>.  <literal>FOUND</literal> starts out
     false within each <application>PL/pgSQL</application> function call.
     It is set by each of the following types of statements:
         <itemizedlist>
          <listitem>
           <para>
                A <command>SELECT INTO</command> statement sets
                <literal>FOUND</literal> true if it returns a row, false if no
                row is returned.
           </para>
          </listitem>
          <listitem>
           <para>
                A <command>PERFORM</> statement sets <literal>FOUND</literal>
                true if it produces (and discards) a row, false if no row is
                produced.
           </para>
          </listitem>
          <listitem>
           <para>
                <command>UPDATE</>, <command>INSERT</>, and <command>DELETE</>
                statements set <literal>FOUND</literal> true if at least one
                row is affected, false if no row is affected.
           </para>
          </listitem>
          <listitem>
           <para>
                A <command>FETCH</> statement sets <literal>FOUND</literal>
                true if it returns a row, false if no row is returned.
           </para>
          </listitem>
          <listitem>
           <para>
                A <command>FOR</> statement sets <literal>FOUND</literal> true
                if it iterates one or more times, else false.  This applies to
                all three variants of the <command>FOR</> statement (integer
                <command>FOR</> loops, record-set <command>FOR</> loops, and
                dynamic record-set <command>FOR</>
                loops). <literal>FOUND</literal> is set this way when the
                <command>FOR</> loop exits; inside the execution of the loop,
                <literal>FOUND</literal> is not modified by the
                <command>FOR</> statement, although it may be changed by the
                execution of other statements within the loop body.
           </para>
          </listitem>
         </itemizedlist>

     <literal>FOUND</literal> is a local variable within each
     <application>PL/pgSQL</application> function; so any changes
     to it affect only the current function.
    </para>

   </sect2>
  </sect1>

  <sect1 id="plpgsql-control-structures">
   <title>Control Structures</title>

   <para>
    Control structures are probably the most useful (and
    important) part of <application>PL/pgSQL</>. With
    <application>PL/pgSQL</>'s control structures,
    you can manipulate <productname>PostgreSQL</> data in a very
    flexible and powerful way. 
   </para>

   <sect2 id="plpgsql-statements-returning">
    <title>Returning From a Function</title>

    <para>
     There are two commands available that allow you to return data
     from a function: <command>RETURN</command> and <command>RETURN
     NEXT</command>.
    </para>

    <sect3>
     <title><command>RETURN</></title>

<synopsis>
RETURN <replaceable>expression</replaceable>;
</synopsis>

     <para>
      <command>RETURN</command> with an expression terminates the
      function and returns the value of
      <replaceable>expression</replaceable> to the caller.  This form
      is to be used for <application>PL/pgSQL</> functions that do
      not return a set.
     </para>

     <para>
      When returning a scalar type, any expression can be used. The
      expression's result will be automatically cast into the
      function's return type as described for assignments. To return a
      composite (row) value, you must write a record or row variable
      as the <replaceable>expression</replaceable>.
     </para>

     <para>
      The return value of a function cannot be left undefined. If
      control reaches the end of the top-level block of the function
      without hitting a <command>RETURN</command> statement, a run-time
      error will occur.
     </para>

     <para>
      If you have declared the function to
      return <type>void</type>, a <command>RETURN</command> statement
      must still be provided; but in this case the expression following
      <command>RETURN</command> is optional and will be ignored if present.
     </para>
    </sect3>

    <sect3>
     <title><command>RETURN NEXT</></title>

<synopsis>
RETURN NEXT <replaceable>expression</replaceable>;
</synopsis>

     <para>
      When a <application>PL/pgSQL</> function is declared to return
      <literal>SETOF <replaceable>sometype</></literal>, the procedure
      to follow is slightly different.  In that case, the individual
      items to return are specified in <command>RETURN NEXT</command>
      commands, and then a final <command>RETURN</command> command
      with no argument is used to indicate that the function has
      finished executing.  <command>RETURN NEXT</command> can be used
      with both scalar and composite data types; in the latter case, an
      entire <quote>table</quote> of results will be returned.
     </para>

     <para>
      Functions that use <command>RETURN NEXT</command> should be
      called in the following fashion:

<programlisting>
SELECT * FROM some_func();
</programlisting>

      That is, the function must be used as a table source in a
      <literal>FROM</literal> clause.
     </para>

     <para>
      <command>RETURN NEXT</command> does not actually return from the
      function; it simply saves away the value of the expression.
      Execution then continues with the next statement in
      the <application>PL/pgSQL</> function.  As successive
      <command>RETURN NEXT</command> commands are executed, the result
      set is built up.  A final <command>RETURN</command>, which should
      have no argument, causes control to exit the function.
     </para>

     <note>
      <para>
       The current implementation of <command>RETURN NEXT</command>
       for <application>PL/pgSQL</> stores the entire result set
       before returning from the function, as discussed above.  That
       means that if a <application>PL/pgSQL</> function produces a
       very large result set, performance may be poor: data will be
       written to disk to avoid memory exhaustion, but the function
       itself will not return until the entire result set has been
       generated.  A future version of <application>PL/pgSQL</> may
       allow users to define set-returning functions
       that do not have this limitation.  Currently, the point at
       which data begins being written to disk is controlled by the
       <varname>work_mem</> configuration variable.  Administrators
       who have sufficient memory to store larger result sets in
       memory should consider increasing this parameter.
      </para>
     </note>
    </sect3>
   </sect2>

   <sect2 id="plpgsql-conditionals">
    <title>Conditionals</title>

    <para>
     <literal>IF</> statements let you execute commands based on
     certain conditions.  <application>PL/pgSQL</> has five forms of
     <literal>IF</>:
    <itemizedlist>
     <listitem>
      <para><literal>IF ... THEN</></>
     </listitem>
     <listitem>
      <para><literal>IF ... THEN ... ELSE</></>
     </listitem>
     <listitem>
      <para><literal>IF ... THEN ... ELSE IF</></>
     </listitem>
     <listitem>
      <para><literal>IF ... THEN ... ELSIF ... THEN ... ELSE</></>
     </listitem>
     <listitem>
      <para><literal>IF ... THEN ... ELSEIF ... THEN ... ELSE</></>
     </listitem>
    </itemizedlist>
    </para>

    <sect3>
     <title><literal>IF-THEN</></title>

<synopsis>
IF <replaceable>boolean-expression</replaceable> THEN
    <replaceable>statements</replaceable>
END IF;
</synopsis>

       <para>
        <literal>IF-THEN</literal> statements are the simplest form of
        <literal>IF</literal>. The statements between
        <literal>THEN</literal> and <literal>END IF</literal> will be
        executed if the condition is true. Otherwise, they are
        skipped.
       </para>

       <para>
        Example:
<programlisting>
IF v_user_id &lt;&gt; 0 THEN
    UPDATE users SET email = v_email WHERE user_id = v_user_id;
END IF;
</programlisting>
       </para>
     </sect3>

     <sect3>
      <title><literal>IF-THEN-ELSE</></title>

<synopsis>
IF <replaceable>boolean-expression</replaceable> THEN
    <replaceable>statements</replaceable>
ELSE
    <replaceable>statements</replaceable>
END IF;
</synopsis>

       <para>
        <literal>IF-THEN-ELSE</literal> statements add to
        <literal>IF-THEN</literal> by letting you specify an
        alternative set of statements that should be executed if the
        condition evaluates to false.
       </para>

       <para>
        Examples:
<programlisting>
IF parentid IS NULL OR parentid = ''
THEN
    RETURN fullname;
ELSE
    RETURN hp_true_filename(parentid) || '/' || fullname;
END IF;
</programlisting>

<programlisting>
IF v_count &gt; 0 THEN 
    INSERT INTO users_count (count) VALUES (v_count);
    RETURN 't';
ELSE
    RETURN 'f';
END IF;
</programlisting>
     </para>
    </sect3>

     <sect3>
      <title><literal>IF-THEN-ELSE IF</></title>

       <para>
        <literal>IF</literal> statements can be nested, as in the
        following example:

<programlisting>
IF demo_row.sex = 'm' THEN
    pretty_sex := 'man';
ELSE
    IF demo_row.sex = 'f' THEN
        pretty_sex := 'woman';
    END IF;
END IF;
</programlisting>
       </para>

       <para>
        When you use this form, you are actually nesting an
        <literal>IF</literal> statement inside the
        <literal>ELSE</literal> part of an outer <literal>IF</literal>
        statement. Thus you need one <literal>END IF</literal>
        statement for each nested <literal>IF</literal> and one for the parent
        <literal>IF-ELSE</literal>.  This is workable but grows
        tedious when there are many alternatives to be checked.
        Hence the next form.
       </para>
     </sect3>

     <sect3>
      <title><literal>IF-THEN-ELSIF-ELSE</></title>

<synopsis>
IF <replaceable>boolean-expression</replaceable> THEN
    <replaceable>statements</replaceable>
<optional> ELSIF <replaceable>boolean-expression</replaceable> THEN
    <replaceable>statements</replaceable>
<optional> ELSIF <replaceable>boolean-expression</replaceable> THEN
    <replaceable>statements</replaceable>
    ...
</optional>
</optional>
<optional> ELSE
    <replaceable>statements</replaceable> </optional>
END IF;
</synopsis>

       <para>
        <literal>IF-THEN-ELSIF-ELSE</> provides a more convenient
        method of checking many alternatives in one statement.
        Formally it is equivalent to nested
        <literal>IF-THEN-ELSE-IF-THEN</> commands, but only one
        <literal>END IF</> is needed.
       </para>

       <para>
        Here is an example:

<programlisting>
IF number = 0 THEN
    result := 'zero';
ELSIF number &gt; 0 THEN 
    result := 'positive';
ELSIF number &lt; 0 THEN
    result := 'negative';
ELSE
    -- hmm, the only other possibility is that number is null
    result := 'NULL';
END IF;
</programlisting>
       </para>
     </sect3>

     <sect3>
      <title><literal>IF-THEN-ELSEIF-ELSE</></title>

      <para>
       <literal>ELSEIF</> is an alias for <literal>ELSIF</>.
      </para>
     </sect3>
   </sect2>

   <sect2 id="plpgsql-control-structures-loops">
    <title>Simple Loops</title>

    <indexterm zone="plpgsql-control-structures-loops">
     <primary>loop</primary>
     <secondary>in PL/pgSQL</secondary>
    </indexterm>

    <para>
     With the <literal>LOOP</>, <literal>EXIT</>, <literal>WHILE</>,
     and <literal>FOR</> statements, you can arrange for your
     <application>PL/pgSQL</application> function to repeat a series
     of commands.
    </para>

    <sect3>
     <title><literal>LOOP</></title>

<synopsis>
<optional>&lt;&lt;<replaceable>label</replaceable>&gt;&gt;</optional>
LOOP
    <replaceable>statements</replaceable>
END LOOP;
</synopsis>

     <para>
      <literal>LOOP</> defines an unconditional loop that is repeated indefinitely
      until terminated by an <literal>EXIT</> or <command>RETURN</command>
      statement.  The optional label can be used by <literal>EXIT</> statements in
      nested loops to specify which level of nesting should be
      terminated.
     </para>
    </sect3>

     <sect3>
      <title><literal>EXIT</></title>

<synopsis>
EXIT <optional> <replaceable>label</replaceable> </optional> <optional> WHEN <replaceable>expression</replaceable> </optional>;
</synopsis>

       <para>
        If no <replaceable>label</replaceable> is given,
        the innermost loop is terminated and the
        statement following <literal>END LOOP</> is executed next.
        If <replaceable>label</replaceable> is given, it
        must be the label of the current or some outer level of nested loop
        or block. Then the named loop or block is terminated and control
        continues with the statement after the loop's/block's corresponding
        <literal>END</>.
       </para>

       <para>
        If <literal>WHEN</> is present, loop exit occurs only if the specified
        condition is true, otherwise control passes to the statement after
        <literal>EXIT</>.
       </para>

       <para>
        <literal>EXIT</> can be used to cause early exit from all types of
        loops; it is not limited to use with unconditional loops.
       </para>

       <para>
        Examples:
<programlisting>
LOOP
    -- some computations
    IF count &gt; 0 THEN
        EXIT;  -- exit loop
    END IF;
END LOOP;

LOOP
    -- some computations
    EXIT WHEN count &gt; 0;  -- same result as previous example
END LOOP;

BEGIN
    -- some computations
    IF stocks &gt; 100000 THEN
        EXIT;  -- causes exit from the BEGIN block
    END IF;
END;
</programlisting>
       </para>
     </sect3>

     <sect3>
      <title><literal>WHILE</></title>

<synopsis>
<optional>&lt;&lt;<replaceable>label</replaceable>&gt;&gt;</optional>
WHILE <replaceable>expression</replaceable> LOOP
    <replaceable>statements</replaceable>
END LOOP;
</synopsis>

       <para>
        The <literal>WHILE</> statement repeats a
        sequence of statements so long as the condition expression
        evaluates to true.  The condition is checked just before
        each entry to the loop body.
       </para>

       <para>
        For example:
<programlisting>
WHILE amount_owed &gt; 0 AND gift_certificate_balance &gt; 0 LOOP
    -- some computations here
END LOOP;

WHILE NOT boolean_expression LOOP
    -- some computations here
END LOOP;
</programlisting>
       </para>
     </sect3>

     <sect3>
      <title><literal>FOR</> (integer variant)</title>

<synopsis>
<optional>&lt;&lt;<replaceable>label</replaceable>&gt;&gt;</optional>
FOR <replaceable>name</replaceable> IN <optional> REVERSE </optional> <replaceable>expression</replaceable> .. <replaceable>expression</replaceable> LOOP
    <replaceable>statements</replaceable>
END LOOP;
</synopsis>

       <para>
        This form of <literal>FOR</> creates a loop that iterates over a range of integer
        values. The variable 
        <replaceable>name</replaceable> is automatically defined as type
        <type>integer</> and exists only inside the loop. The two expressions giving
        the lower and upper bound of the range are evaluated once when entering
        the loop. The iteration step is normally 1, but is -1 when <literal>REVERSE</> is
        specified.
       </para>

       <para>
        Some examples of integer <literal>FOR</> loops:
<programlisting>
FOR i IN 1..10 LOOP
    -- some computations here
    RAISE NOTICE 'i is %', i;
END LOOP;

FOR i IN REVERSE 10..1 LOOP
    -- some computations here
END LOOP;
</programlisting>
       </para>

       <para>
        If the lower bound is greater than the upper bound (or less than,
        in the <literal>REVERSE</> case), the loop body is not
        executed at all.  No error is raised.
       </para>
     </sect3>
   </sect2>

   <sect2 id="plpgsql-records-iterating">
    <title>Looping Through Query Results</title>

    <para>
     Using a different type of <literal>FOR</> loop, you can iterate through
     the results of a query and manipulate that data
     accordingly. The syntax is:
<synopsis>
<optional>&lt;&lt;<replaceable>label</replaceable>&gt;&gt;</optional>
FOR <replaceable>record_or_row</replaceable> IN <replaceable>query</replaceable> LOOP
    <replaceable>statements</replaceable>
END LOOP;
</synopsis>
     The record or row variable is successively assigned each row
     resulting from the <replaceable>query</replaceable> (which must be a
     <command>SELECT</command> command) and the loop body is executed for each
     row. Here is an example:
<programlisting>
CREATE FUNCTION cs_refresh_mviews() RETURNS integer AS $$
DECLARE
    mviews RECORD;
BEGIN
    PERFORM cs_log('Refreshing materialized views...');

    FOR mviews IN SELECT * FROM cs_materialized_views ORDER BY sort_key LOOP

        -- Now "mviews" has one record from cs_materialized_views

        PERFORM cs_log('Refreshing materialized view ' || quote_ident(mviews.mv_name) || ' ...');
        EXECUTE 'TRUNCATE TABLE ' || quote_ident(mviews.mv_name);
        EXECUTE 'INSERT INTO ' || quote_ident(mviews.mv_name) || ' ' || mviews.mv_query;
    END LOOP;

    PERFORM cs_log('Done refreshing materialized views.');
    RETURN 1;
END;
$$ LANGUAGE plpgsql;
</programlisting>

     If the loop is terminated by an <literal>EXIT</> statement, the last
     assigned row value is still accessible after the loop.
    </para>

    <para>
     The <literal>FOR-IN-EXECUTE</> statement is another way to iterate over
     rows:
<synopsis>
<optional>&lt;&lt;<replaceable>label</replaceable>&gt;&gt;</optional>
FOR <replaceable>record_or_row</replaceable> IN EXECUTE <replaceable>text_expression</replaceable> LOOP 
    <replaceable>statements</replaceable>
END LOOP;
</synopsis>
     This is like the previous form, except that the source
     <command>SELECT</command> statement is specified as a string
     expression, which is evaluated and replanned on each entry to
     the <literal>FOR</> loop.  This allows the programmer to choose the speed of
     a preplanned query or the flexibility of a dynamic query, just
     as with a plain <command>EXECUTE</command> statement.
    </para>

    <note>
    <para>
     The <application>PL/pgSQL</> parser presently distinguishes the
     two kinds of <literal>FOR</> loops (integer or query result) by checking
     whether <literal>..</> appears outside any parentheses between
     <literal>IN</> and <literal>LOOP</>.  If <literal>..</> is not seen then
     the loop is presumed to be a loop over rows.  Mistyping the <literal>..</>
     is thus likely to lead to a complaint along the lines of
     <quote>loop variable of loop over rows must be a record or row variable</>,
     rather than the simple syntax error one might expect to get.
    </para>
    </note>
   </sect2>

   <sect2 id="plpgsql-error-trapping">
    <title>Trapping Errors</title>

    <para>
     By default, any error occurring in a <application>PL/pgSQL</>
     function aborts execution of the function, and indeed of the
     surrounding transaction as well.  You can trap errors and recover
     from them by using a <command>BEGIN</> block with an
     <literal>EXCEPTION</> clause.  The syntax is an extension of the
     normal syntax for a <command>BEGIN</> block:

<synopsis>
<optional> &lt;&lt;<replaceable>label</replaceable>&gt;&gt; </optional>
<optional> DECLARE
    <replaceable>declarations</replaceable> </optional>
BEGIN
    <replaceable>statements</replaceable>
EXCEPTION
    WHEN <replaceable>condition</replaceable> <optional> OR <replaceable>condition</replaceable> ... </optional> THEN
        <replaceable>handler_statements</replaceable>
    <optional> WHEN <replaceable>condition</replaceable> <optional> OR <replaceable>condition</replaceable> ... </optional> THEN
          <replaceable>handler_statements</replaceable>
      ... </optional>
END;
</synopsis>
    </para>

    <para>
     If no error occurs, this form of block simply executes all the
     <replaceable>statements</replaceable>, and then control passes
     to the next statement after <literal>END</>.  But if an error
     occurs within the <replaceable>statements</replaceable>, further
     processing of the <replaceable>statements</replaceable> is
     abandoned, and control passes to the <literal>EXCEPTION</> list.
     The list is searched for the first <replaceable>condition</replaceable>
     matching the error that occurred.  If a match is found, the
     corresponding <replaceable>handler_statements</replaceable> are
     executed, and then control passes to the next statement after
     <literal>END</>.  If no match is found, the error propagates out
     as though the <literal>EXCEPTION</> clause were not there at all:
     the error can be caught by an enclosing block with
     <literal>EXCEPTION</>, or if there is none it aborts processing
     of the function.
    </para>

    <para>
     The <replaceable>condition</replaceable> names can be any of those
     shown in <xref linkend="errcodes-appendix">.  A category name matches
     any error within its category.
     The special condition name <literal>OTHERS</>
     matches every error type except <literal>QUERY_CANCELED</>.
     (It is possible, but often unwise, to trap
     <literal>QUERY_CANCELED</> by name.)
     Condition names are not case-sensitive.
    </para>

    <para>
     If a new error occurs within the selected
     <replaceable>handler_statements</replaceable>, it cannot be caught
     by this <literal>EXCEPTION</> clause, but is propagated out.
     A surrounding <literal>EXCEPTION</> clause could catch it.
    </para>

    <para>
     When an error is caught by an <literal>EXCEPTION</> clause,
     the local variables of the <application>PL/pgSQL</> function
     remain as they were when the error occurred, but all changes
     to persistent database state within the block are rolled back.
     As an example, consider this fragment:

<programlisting>
    INSERT INTO mytab(firstname, lastname) VALUES('Tom', 'Jones');
    BEGIN
        UPDATE mytab SET firstname = 'Joe' WHERE lastname = 'Jones';
        x := x + 1;
        y := x / 0;
    EXCEPTION
        WHEN division_by_zero THEN
            RAISE NOTICE 'caught division_by_zero';
            RETURN x;
    END;
</programlisting>

     When control reaches the assignment to <literal>y</>, it will
     fail with a <literal>division_by_zero</> error.  This will be caught by
     the <literal>EXCEPTION</> clause.  The value returned in the
     <command>RETURN</> statement will be the incremented value of
     <literal>x</>, but the effects of the <command>UPDATE</> command will
     have been rolled back.  The <command>INSERT</> command preceding the
     block is not rolled back, however, so the end result is that the database
     contains <literal>Tom Jones</> not <literal>Joe Jones</>.
    </para>

    <tip>
     <para>
      A block containing an <literal>EXCEPTION</> clause is significantly
      more expensive to enter and exit than a block without one.  Therefore,
      don't use <literal>EXCEPTION</> without need.
     </para>
    </tip>
  </sect2>
  </sect1>

  <sect1 id="plpgsql-cursors">
   <title>Cursors</title>

   <indexterm zone="plpgsql-cursors">
    <primary>cursor</primary>
    <secondary>in PL/pgSQL</secondary>
   </indexterm>

   <para>
    Rather than executing a whole query at once, it is possible to set
    up a <firstterm>cursor</> that encapsulates the query, and then read
    the query result a few rows at a time. One reason for doing this is
    to avoid memory overrun when the result contains a large number of
    rows. (However, <application>PL/pgSQL</> users do not normally need
    to worry about that, since <literal>FOR</> loops automatically use a cursor
    internally to avoid memory problems.) A more interesting usage is to
    return a reference to a cursor that a function has created, allowing the
    caller to read the rows. This provides an efficient way to return
    large row sets from functions.
   </para>

   <sect2 id="plpgsql-cursor-declarations">
    <title>Declaring Cursor Variables</title>

    <para>
     All access to cursors in <application>PL/pgSQL</> goes through
     cursor variables, which are always of the special data type
     <type>refcursor</>.  One way to create a cursor variable
     is just to declare it as a variable of type <type>refcursor</>.
     Another way is to use the cursor declaration syntax,
     which in general is:
<synopsis>
<replaceable>name</replaceable> CURSOR <optional> ( <replaceable>arguments</replaceable> ) </optional> FOR <replaceable>query</replaceable> ;
</synopsis>
     (<literal>FOR</> may be replaced by <literal>IS</> for
     <productname>Oracle</productname> compatibility.)
     <replaceable>arguments</replaceable>, if specified, is a
     comma-separated list of pairs <literal><replaceable>name</replaceable>
     <replaceable>datatype</replaceable></literal> that define names to be
     replaced by parameter values in the given query.  The actual
     values to substitute for these names will be specified later,
     when the cursor is opened.
    </para>
    <para>
     Some examples:
<programlisting>
DECLARE
    curs1 refcursor;
    curs2 CURSOR FOR SELECT * FROM tenk1;
    curs3 CURSOR (key integer) IS SELECT * FROM tenk1 WHERE unique1 = key;
</programlisting>
     All three of these variables have the data type <type>refcursor</>,
     but the first may be used with any query, while the second has
     a fully specified query already <firstterm>bound</> to it, and the last
     has a parameterized query bound to it.  (<literal>key</> will be
     replaced by an integer parameter value when the cursor is opened.)
     The variable <literal>curs1</>
     is said to be <firstterm>unbound</> since it is not bound to
     any particular query.
    </para>
   </sect2>

   <sect2 id="plpgsql-cursor-opening">
    <title>Opening Cursors</title>

    <para>
     Before a cursor can be used to retrieve rows, it must be
     <firstterm>opened</>. (This is the equivalent action to the SQL
     command <command>DECLARE CURSOR</>.) <application>PL/pgSQL</> has
     three forms of the <command>OPEN</> statement, two of which use unbound
     cursor variables while the third uses a bound cursor variable.
    </para>

    <sect3>
     <title><command>OPEN FOR SELECT</command></title>

<synopsis>
OPEN <replaceable>unbound_cursor</replaceable> FOR SELECT ...;
</synopsis>

       <para>
    The cursor variable is opened and given the specified query to
        execute.  The cursor cannot be open already, and it must have been
        declared as an unbound cursor (that is, as a simple
        <type>refcursor</> variable).  The <command>SELECT</command> query
        is treated in the same way as other <command>SELECT</command>
        statements in <application>PL/pgSQL</>: <application>PL/pgSQL</>
        variable names are substituted, and the query plan is cached for
        possible reuse.
       </para>

       <para>
        An example:
<programlisting>
OPEN curs1 FOR SELECT * FROM foo WHERE key = mykey;
</programlisting>
       </para>
     </sect3>

    <sect3>
     <title><command>OPEN FOR EXECUTE</command></title>

<synopsis>
OPEN <replaceable>unbound_cursor</replaceable> FOR EXECUTE <replaceable class="command">query_string</replaceable>;
</synopsis>

         <para>
          The cursor variable is opened and given the specified query to
          execute.  The cursor cannot be open already, and it must have been
          declared as an unbound cursor (that is, as a simple
          <type>refcursor</> variable).  The query is specified as a string
          expression in the same way as in the <command>EXECUTE</command>
          command.  As usual, this gives flexibility so the query can vary
          from one run to the next.
       </para>

       <para>
        An example:
<programlisting>
OPEN curs1 FOR EXECUTE 'SELECT * FROM ' || quote_ident($1);
</programlisting>
       </para>
     </sect3>

    <sect3>
     <title>Opening a Bound Cursor</title>

<synopsis>
OPEN <replaceable>bound_cursor</replaceable> <optional> ( <replaceable>argument_values</replaceable> ) </optional>;
</synopsis>

         <para>
          This form of <command>OPEN</command> is used to open a cursor
          variable whose query was bound to it when it was declared.  The
          cursor cannot be open already.  A list of actual argument value
          expressions must appear if and only if the cursor was declared to
          take arguments.  These values will be substituted in the query.
          The query plan for a bound cursor is always considered cacheable;
          there is no equivalent of <command>EXECUTE</command> in this case.
         </para>

    <para>
     Examples:
<programlisting>
OPEN curs2;
OPEN curs3(42);
</programlisting>
       </para>
     </sect3>
   </sect2>

   <sect2 id="plpgsql-cursor-using">
    <title>Using Cursors</title>

    <para>
     Once a cursor has been opened, it can be manipulated with the
     statements described here.
    </para>

    <para>
     These manipulations need not occur in the same function that
     opened the cursor to begin with.  You can return a <type>refcursor</>
     value out of a function and let the caller operate on the cursor.
     (Internally, a <type>refcursor</> value is simply the string name
     of a so-called portal containing the active query for the cursor.  This name
     can be passed around, assigned to other <type>refcursor</> variables,
     and so on, without disturbing the portal.)
    </para>

    <para>
     All portals are implicitly closed at transaction end.  Therefore
     a <type>refcursor</> value is usable to reference an open cursor
     only until the end of the transaction.
    </para>

    <sect3>
     <title><literal>FETCH</></title>

<synopsis>
FETCH <replaceable>cursor</replaceable> INTO <replaceable>target</replaceable>;
</synopsis>

         <para>
          <command>FETCH</command> retrieves the next row from the
          cursor into a target, which may be a row variable, a record
          variable, or a comma-separated list of simple variables, just like
          <command>SELECT INTO</command>.  As with <command>SELECT
           INTO</command>, the special variable <literal>FOUND</literal> may
          be checked to see whether a row was obtained or not.
         </para>

    <para>
     An example:
<programlisting>
FETCH curs1 INTO rowvar;
FETCH curs2 INTO foo, bar, baz;
</programlisting>
       </para>
     </sect3>

    <sect3>
     <title><literal>CLOSE</></title>

<synopsis>
CLOSE <replaceable>cursor</replaceable>;
</synopsis>

       <para>
        <command>CLOSE</command> closes the portal underlying an open
        cursor.  This can be used to release resources earlier than end of
        transaction, or to free up the cursor variable to be opened again.
       </para>

       <para>
        An example:
<programlisting>
CLOSE curs1;
</programlisting>
       </para>
     </sect3>

    <sect3>
     <title>Returning Cursors</title>

       <para>
        <application>PL/pgSQL</> functions can return cursors to the
        caller. This is useful to return multiple rows or columns,
        especially with very large result sets.  To do this, the function
        opens the cursor and returns the cursor name to the caller (or simply
        opens the cursor using a portal name specified by or otherwise known
        to the caller).  The caller can then fetch rows from the cursor. The
        cursor can be closed by the caller, or it will be closed automatically
        when the transaction closes.
       </para>

       <para>
        The portal name used for a cursor can be specified by the
        programmer or automatically generated.  To specify a portal name,
        simply assign a string to the <type>refcursor</> variable before
        opening it.  The string value of the <type>refcursor</> variable
        will be used by <command>OPEN</> as the name of the underlying portal.
        However, if the <type>refcursor</> variable is null,
        <command>OPEN</> automatically generates a name that does not
        conflict with any existing portal, and assigns it to the
        <type>refcursor</> variable.
       </para>

       <note>
        <para>
         A bound cursor variable is initialized to the string value
         representing its name, so that the portal name is the same as
         the cursor variable name, unless the programmer overrides it
         by assignment before opening the cursor.  But an unbound cursor
         variable defaults to the null value initially , so it will receive
         an automatically-generated unique name, unless overridden.
        </para>
       </note>

       <para>
        The following example shows one way a cursor name can be supplied by
        the caller:

<programlisting>
CREATE TABLE test (col text);
INSERT INTO test VALUES ('123');

CREATE FUNCTION reffunc(refcursor) RETURNS refcursor AS '
BEGIN
    OPEN $1 FOR SELECT col FROM test;
    RETURN $1;
END;
' LANGUAGE plpgsql;

BEGIN;
SELECT reffunc('funccursor');
FETCH ALL IN funccursor;
COMMIT;
</programlisting>
       </para>

       <para>
        The following example uses automatic cursor name generation:

<programlisting>
CREATE FUNCTION reffunc2() RETURNS refcursor AS '
DECLARE
    ref refcursor;
BEGIN
    OPEN ref FOR SELECT col FROM test;
    RETURN ref;
END;
' LANGUAGE plpgsql;

BEGIN;
SELECT reffunc2();

      reffunc2      
--------------------
 &lt;unnamed cursor 1&gt;
(1 row)

FETCH ALL IN "&lt;unnamed cursor 1&gt;";
COMMIT;
</programlisting>
       </para>

       <para>
        The following example shows one way to return multiple cursors
        from a single function:

<programlisting>
CREATE FUNCTION myfunc(refcursor, refcursor) RETURNS SETOF refcursor AS $$
BEGIN
    OPEN $1 FOR SELECT * FROM table_1;
    RETURN NEXT $1;
    OPEN $2 FOR SELECT * FROM table_2;
    RETURN NEXT $2;
    RETURN;
END;
$$ LANGUAGE plpgsql;

-- need to be in a transaction to use cursors.
BEGIN;

SELECT * FROM myfunc('a', 'b');

FETCH ALL FROM a;
FETCH ALL FROM b;
COMMIT;
</programlisting>
       </para>
     </sect3>
   </sect2>
  </sect1>

  <sect1 id="plpgsql-errors-and-messages">
   <title>Errors and Messages</title>

   <para>
    Use the <command>RAISE</command> statement to report messages and
    raise errors.

<synopsis>
RAISE <replaceable class="parameter">level</replaceable> '<replaceable class="parameter">format</replaceable>' <optional>, <replaceable class="parameter">variable</replaceable> <optional>, ...</optional></optional>;
</synopsis>

    Possible levels are <literal>DEBUG</literal>,
    <literal>LOG</literal>, <literal>INFO</literal>,
    <literal>NOTICE</literal>, <literal>WARNING</literal>,
    and <literal>EXCEPTION</literal>.
    <literal>EXCEPTION</literal> raises an error (which normally aborts the
    current transaction); the other levels only generate messages of different
    priority levels.
    Whether messages of a particular priority are reported to the client,
    written to the server log, or both is controlled by the
    <xref linkend="guc-log-min-messages"> and
    <xref linkend="guc-client-min-messages"> configuration
    variables. See <xref linkend="runtime-config"> for more
    information.
   </para>

   <para>
    Inside the format string, <literal>%</literal> is replaced by the
    next optional argument's string representation. Write
    <literal>%%</literal> to emit a literal <literal>%</literal>. Note
    that the optional arguments must presently be simple variables,
    not expressions, and the format must be a simple string literal.
   </para>

   <!--
   This example should work, but does not:
        RAISE NOTICE 'Id number ' || key || ' not found!';
   Put it back when we allow non-string-literal formats.
    -->

   <para>
    In this example, the value of <literal>v_job_id</> will replace the
    <literal>%</literal> in the string:
<programlisting>
RAISE NOTICE 'Calling cs_create_job(%)', v_job_id;
</programlisting>
   </para>

   <para>
    This example will abort the transaction with the given error message:
<programlisting>
RAISE EXCEPTION 'Nonexistent ID --> %', user_id;
</programlisting>
   </para>

    <para>
     <command>RAISE EXCEPTION</command> presently always generates
     the same SQLSTATE code, <literal>P0001</>, no matter what message
     it is invoked with.  It is possible to trap this exception with
     <literal>EXCEPTION ... WHEN RAISE_EXCEPTION THEN ...</> but there
     is no way to tell one <command>RAISE</> from another.
    </para>
 </sect1>

 <sect1 id="plpgsql-trigger">
  <title>Trigger Procedures</title>

  <indexterm zone="plpgsql-trigger">
   <primary>trigger</primary>
   <secondary>in PL/pgSQL</secondary>
  </indexterm>

  <para>
        <application>PL/pgSQL</application> can be used to define trigger
        procedures. A trigger procedure is created with the
        <command>CREATE FUNCTION</> command, declaring it as a function with
        no arguments and a return type of <type>trigger</type>.  Note that
        the function must be declared with no arguments even if it expects
        to receive arguments specified in <command>CREATE TRIGGER</> &mdash;
        trigger arguments are passed via <varname>TG_ARGV</>, as described
        below.
  </para>

  <para>
   When a <application>PL/pgSQL</application> function is called as a
   trigger, several special variables are created automatically in the 
   top-level block. They are:

   <variablelist>
    <varlistentry>
     <term><varname>NEW</varname></term>
     <listitem>
      <para>
       Data type <type>RECORD</type>; variable holding the new
       database row for <command>INSERT</>/<command>UPDATE</> operations in row-level
       triggers. This variable is <symbol>NULL</symbol> in statement-level triggers.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term><varname>OLD</varname></term>
     <listitem>
      <para>
       Data type <type>RECORD</type>; variable holding the old
       database row for <command>UPDATE</>/<command>DELETE</> operations in row-level
       triggers. This variable is <symbol>NULL</symbol> in statement-level triggers.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term><varname>TG_NAME</varname></term>
     <listitem>
      <para>
       Data type <type>name</type>; variable that contains the name of the trigger actually
       fired.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term><varname>TG_WHEN</varname></term>
     <listitem>
      <para>
       Data type <type>text</type>; a string of either 
              <literal>BEFORE</literal> or <literal>AFTER</literal>
              depending on the trigger's definition.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term><varname>TG_LEVEL</varname></term>
     <listitem>
      <para>
       Data type <type>text</type>; a string of either
       <literal>ROW</literal> or <literal>STATEMENT</literal>
       depending on the trigger's definition.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term><varname>TG_OP</varname></term>
     <listitem>
      <para>
       Data type <type>text</type>; a string of
       <literal>INSERT</literal>, <literal>UPDATE</literal>, or
       <literal>DELETE</literal> telling for which operation the
       trigger was fired.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term><varname>TG_RELID</varname></term>
     <listitem>
      <para>
       Data type <type>oid</type>; the object ID of the table that caused the
       trigger invocation.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term><varname>TG_RELNAME</varname></term>
     <listitem>
      <para>
       Data type <type>name</type>; the name of the table that caused the trigger
       invocation.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term><varname>TG_NARGS</varname></term>
     <listitem>
      <para>
       Data type <type>integer</type>; the number of arguments given to the trigger
       procedure in the <command>CREATE TRIGGER</command> statement.
      </para>
     </listitem>
    </varlistentry>

    <varlistentry>
     <term><varname>TG_ARGV[]</varname></term>
     <listitem>
      <para>
       Data type array of <type>text</type>; the arguments from
              the <command>CREATE TRIGGER</command> statement.
       The index counts from 0. Invalid
       indices (less than 0 or greater than or equal to <varname>tg_nargs</>) result in a null value.
      </para>
     </listitem>
    </varlistentry>
   </variablelist>
  </para>

   <para>
    A trigger function must return either <symbol>NULL</symbol> or a
    record/row value having exactly the structure of the table the
    trigger was fired for.
   </para>

   <para>
    Row-level triggers fired <literal>BEFORE</> may return null to signal the
    trigger manager to skip the rest of the operation for this row
    (i.e., subsequent triggers are not fired, and the
    <command>INSERT</>/<command>UPDATE</>/<command>DELETE</> does not occur
    for this row).  If a nonnull 
    value is returned then the operation proceeds with that row value.
    Returning a row value different from the original value
    of <varname>NEW</> alters the row that will be inserted or updated
    (but has no direct effect in the <command>DELETE</> case).
    To alter the row to be stored, it is possible to replace single values
    directly in <varname>NEW</> and return the modified <varname>NEW</>,
    or to build a complete new record/row to return.
   </para>

   <para>
    The return value of a <literal>BEFORE</> or <literal>AFTER</>
    statement-level trigger or an <literal>AFTER</> row-level trigger is
    always ignored; it may as well be null. However, any of these types of
    triggers can still abort the entire operation by raising an error.
   </para>

   <para>
    <xref linkend="plpgsql-trigger-example"> shows an example of a
    trigger procedure in <application>PL/pgSQL</application>.
   </para>

   <example id="plpgsql-trigger-example">
    <title>A <application>PL/pgSQL</application> Trigger Procedure</title>

    <para>
     This example trigger ensures that any time a row is inserted or updated
     in the table, the current user name and time are stamped into the
     row. And it checks that an employee's name is given and that the
     salary is a positive value.
    </para>

<programlisting>
CREATE TABLE emp (
    empname text,
    salary integer,
    last_date timestamp,
    last_user text
);

CREATE FUNCTION emp_stamp() RETURNS trigger AS $emp_stamp$
    BEGIN
        -- Check that empname and salary are given
        IF NEW.empname IS NULL THEN
            RAISE EXCEPTION 'empname cannot be null';
        END IF;
        IF NEW.salary IS NULL THEN
            RAISE EXCEPTION '% cannot have null salary', NEW.empname;
        END IF;

        -- Who works for us when she must pay for it?
        IF NEW.salary &lt; 0 THEN
            RAISE EXCEPTION '% cannot have a negative salary', NEW.empname;
        END IF;

        -- Remember who changed the payroll when
        NEW.last_date := 'now';
        NEW.last_user := current_user;
        RETURN NEW;
    END;
$emp_stamp$ LANGUAGE plpgsql;

CREATE TRIGGER emp_stamp BEFORE INSERT OR UPDATE ON emp
    FOR EACH ROW EXECUTE PROCEDURE emp_stamp();
</programlisting>
   </example>

   <para>
    Another way to log changes to a table involves creating a new table that
    holds a row for each insert, update, or delete that occurs. This approach
    can be thought of as auditing changes to a table.
    <xref linkend="plpgsql-trigger-audit-example"> shows an example of an
    audit trigger procedure in <application>PL/pgSQL</application>.
   </para>

   <example id="plpgsql-trigger-audit-example">
    <title>A <application>PL/pgSQL</application> Trigger Procedure For Auditing</title>

    <para>
     This example trigger ensures that any insert, update or delete of a row
     in the <literal>emp</literal> table is recorded (i.e., audited) in the <literal>emp_audit</literal> table. 
     The current time and user name are stamped into the row, together with 
     the type of operation performed on it.
    </para>

<programlisting>
CREATE TABLE emp (
    empname           text NOT NULL,
    salary            integer
);

CREATE TABLE emp_audit( 
    operation         char(1)   NOT NULL,
    stamp             timestamp NOT NULL,
    userid            text      NOT NULL,
    empname           text      NOT NULL,
    salary integer
);

CREATE OR REPLACE FUNCTION process_emp_audit() RETURNS TRIGGER AS $emp_audit$
    BEGIN
        --
        -- Create a row in emp_audit to reflect the operation performed on emp,
        -- make use of the special variable TG_OP to work out the operation.
        --
        IF (TG_OP = 'DELETE') THEN
            INSERT INTO emp_audit SELECT 'D', now(), user, OLD.*;
            RETURN OLD;
        ELSIF (TG_OP = 'UPDATE') THEN
            INSERT INTO emp_audit SELECT 'U', now(), user, NEW.*;
            RETURN NEW;
        ELSIF (TG_OP = 'INSERT') THEN
            INSERT INTO emp_audit SELECT 'I', now(), user, NEW.*;
            RETURN NEW;
        END IF;
        RETURN NULL; -- result is ignored since this is an AFTER trigger
    END;
$emp_audit$ language plpgsql;

CREATE TRIGGER emp_audit
AFTER INSERT OR UPDATE OR DELETE ON emp
    FOR EACH ROW EXECUTE PROCEDURE process_emp_audit();
</programlisting>
   </example>

   <para>
    One use of triggers is to maintain a summary table
    of another table. The resulting summary can be used in place of the 
    original table for certain queries &mdash; often with vastly reduced run 
    times.
    This technique is commonly used in Data Warehousing, where the tables
    of measured or observed data (called fact tables) can be extremely large.
    <xref linkend="plpgsql-trigger-summary-example"> shows an example of a
    trigger procedure in <application>PL/pgSQL</application> that maintains
    a summary table for a fact table in a data warehouse.
   </para>


   <example id="plpgsql-trigger-summary-example">
    <title>A <application>PL/pgSQL</application> Trigger Procedure For Maintaining A Summary Table</title>

    <para>
     The schema detailed here is partly based on the <emphasis>Grocery Store
     </emphasis> example from <emphasis>The Data Warehouse Toolkit</emphasis> 
     by Ralph Kimball.
    </para>

<programlisting>
--
-- Main tables - time dimension and sales fact.
--
CREATE TABLE time_dimension (
    time_key                    integer NOT NULL,
    day_of_week                 integer NOT NULL,
    day_of_month                integer NOT NULL,
    month                       integer NOT NULL,
    quarter                     integer NOT NULL,
    year                        integer NOT NULL
);
CREATE UNIQUE INDEX time_dimension_key ON time_dimension(time_key);

CREATE TABLE sales_fact (
    time_key                    integer NOT NULL,
    product_key                 integer NOT NULL,
    store_key                   integer NOT NULL,
    amount_sold                 numeric(12,2) NOT NULL,
    units_sold                  integer NOT NULL,
    amount_cost                 numeric(12,2) NOT NULL
);
CREATE INDEX sales_fact_time ON sales_fact(time_key);

--
-- Summary table - sales by time.
--
CREATE TABLE sales_summary_bytime (
    time_key                    integer NOT NULL,
    amount_sold                 numeric(15,2) NOT NULL,
    units_sold                  numeric(12) NOT NULL,
    amount_cost                 numeric(15,2) NOT NULL
);
CREATE UNIQUE INDEX sales_summary_bytime_key ON sales_summary_bytime(time_key);

--
-- Function and trigger to amend summarized column(s) on UPDATE, INSERT, DELETE.
--
CREATE OR REPLACE FUNCTION maint_sales_summary_bytime() RETURNS TRIGGER AS $maint_sales_summary_bytime$
    DECLARE
        delta_time_key          integer;
        delta_amount_sold       numeric(15,2);
        delta_units_sold        numeric(12);
        delta_amount_cost       numeric(15,2);
    BEGIN

        -- Work out the increment/decrement amount(s).
        IF (TG_OP = 'DELETE') THEN

            delta_time_key = OLD.time_key;
            delta_amount_sold = -1 * OLD.amount_sold;
            delta_units_sold = -1 * OLD.units_sold;
            delta_amount_cost = -1 * OLD.amount_cost;

        ELSIF (TG_OP = 'UPDATE') THEN

            -- forbid updates that change the time_key -
            -- (probably not too onerous, as DELETE + INSERT is how most 
            -- changes will be made).
            IF ( OLD.time_key != NEW.time_key) THEN
                RAISE EXCEPTION 'Update of time_key : % -&gt; % not allowed', OLD.time_key, NEW.time_key;
            END IF;

            delta_time_key = OLD.time_key;
            delta_amount_sold = NEW.amount_sold - OLD.amount_sold;
            delta_units_sold = NEW.units_sold - OLD.units_sold;
            delta_amount_cost = NEW.amount_cost - OLD.amount_cost;

        ELSIF (TG_OP = 'INSERT') THEN

            delta_time_key = NEW.time_key;
            delta_amount_sold = NEW.amount_sold;
            delta_units_sold = NEW.units_sold;
            delta_amount_cost = NEW.amount_cost;

        END IF;


        -- Update the summary row with the new values.
        UPDATE sales_summary_bytime
            SET amount_sold = amount_sold + delta_amount_sold,
                units_sold = units_sold + delta_units_sold,
                amount_cost = amount_cost + delta_amount_cost
            WHERE time_key = delta_time_key;


        -- There might have been no row with this time_key (e.g new data!).
        IF (NOT FOUND) THEN
            BEGIN
                INSERT INTO sales_summary_bytime (
                            time_key, 
                            amount_sold, 
                            units_sold, 
                            amount_cost)
                    VALUES ( 
                            delta_time_key,
                            delta_amount_sold,
                            delta_units_sold,
                            delta_amount_cost
                           );
            EXCEPTION
                --
                -- Catch race condition when two transactions are adding data
                -- for a new time_key.
                --
                WHEN UNIQUE_VIOLATION THEN
                    UPDATE sales_summary_bytime
                        SET amount_sold = amount_sold + delta_amount_sold,
                            units_sold = units_sold + delta_units_sold,
                            amount_cost = amount_cost + delta_amount_cost
                        WHERE time_key = delta_time_key;

            END;
        END IF;
        RETURN NULL;

    END;
$maint_sales_summary_bytime$ LANGUAGE plpgsql;

CREATE TRIGGER maint_sales_summary_bytime
AFTER INSERT OR UPDATE OR DELETE ON sales_fact
    FOR EACH ROW EXECUTE PROCEDURE maint_sales_summary_bytime();
</programlisting>
   </example>

  </sect1>

  <!-- **** Porting from Oracle PL/SQL **** -->

 <sect1 id="plpgsql-porting">
  <title>Porting from <productname>Oracle</productname> PL/SQL</title>

  <indexterm zone="plpgsql-porting">
   <primary>Oracle</primary>
   <secondary>porting from PL/SQL to PL/pgSQL</secondary>
  </indexterm>

  <indexterm zone="plpgsql-porting">
   <primary>PL/SQL (Oracle)</primary>
   <secondary>porting to PL/pgSQL</secondary>
  </indexterm>

  <para>
   This section explains differences between
   <productname>PostgreSQL</>'s <application>PL/pgSQL</application>
   language and Oracle's <application>PL/SQL</application> language,
   to help developers who port applications from
   <trademark class=registered>Oracle</> to <productname>PostgreSQL</>.
  </para>

  <para>
   <application>PL/pgSQL</application> is similar to PL/SQL in many
   aspects. It is a block-structured, imperative language, and all
   variables have to be declared.  Assignments, loops, conditionals
   are similar.  The main differences you should keep in mind when
   porting from <application>PL/SQL</> to
   <application>PL/pgSQL</application> are:

    <itemizedlist>
     <listitem>
      <para>
       There are no default values for parameters in <productname>PostgreSQL</>.
      </para>
     </listitem>

     <listitem>
      <para>
       You can overload function names in <productname>PostgreSQL</>. This is
       often used to work around the lack of default parameters.
      </para>
     </listitem>

     <listitem>
      <para>
       No need for cursors in <application>PL/pgSQL</>, just put the
       query in the <literal>FOR</literal> statement.  (See <xref
       linkend="plpgsql-porting-ex2">.)
      </para>
     </listitem>

     <listitem>
      <para>
       In <productname>PostgreSQL</> you need to use dollar quoting or escape
       single quotes in the function body. See <xref
       linkend="plpgsql-quote-tips">.
      </para>
     </listitem>

     <listitem>
      <para>
       Instead of packages, use schemas to organize your functions
       into groups.
      </para>
     </listitem>

     <listitem>
      <para>
       Since there are no packages, there are no package-level variables
       either. This is somewhat annoying.  You may be able to keep per-session
       state in temporary tables, instead.
      </para>
     </listitem>
    </itemizedlist>
   </para>

  <sect2>
   <title>Porting Examples</title>

   <para>
    <xref linkend="pgsql-porting-ex1"> shows how to port a simple
    function from <application>PL/SQL</> to <application>PL/pgSQL</>.
   </para>

   <example id="pgsql-porting-ex1">
    <title>Porting a Simple Function from <application>PL/SQL</> to <application>PL/pgSQL</></title>

    <para>
     Here is an <productname>Oracle</productname> <application>PL/SQL</> function:
<programlisting>
CREATE OR REPLACE FUNCTION cs_fmt_browser_version(v_name IN varchar,
                                                  v_version IN varchar)
RETURN varchar IS
BEGIN
    IF v_version IS NULL THEN
        RETURN v_name;
    END IF;
    RETURN v_name || '/' || v_version;
END;
/
show errors;
</programlisting>
    </para>

    <para>
     Let's go through this function and see the differences to <application>PL/pgSQL</>:

     <itemizedlist>
      <listitem>
       <para>
        <productname>Oracle</productname> can have
        <literal>IN</literal>, <literal>OUT</literal>, and
        <literal>INOUT</literal> parameters passed to functions.
        <literal>INOUT</literal>, for example, means that the
        parameter will receive a value and return
        another. <productname>PostgreSQL</> only has <literal>IN</literal>
        parameters, and hence there is no specification of the parameter kind.
       </para>
      </listitem>

      <listitem>
       <para>
        The <literal>RETURN</literal> key word in the function
        prototype (not the function body) becomes
        <literal>RETURNS</literal> in
        <productname>PostgreSQL</productname>.
        Also, <literal>IS</> becomes <literal>AS</>, and you need to
        add a <literal>LANGUAGE</> clause because <application>PL/pgSQL</>
        is not the only possible function language.
       </para>
      </listitem>

      <listitem>
       <para>
        In <productname>PostgreSQL</>, the function body is considered
        to be a string literal, so you need to use quote marks or dollar
        quotes around it.  This substitutes for the terminating <literal>/</>
        in the Oracle approach.
       </para>
      </listitem>

      <listitem>
       <para>
        The <literal>show errors</literal> command does not exist in
        <productname>PostgreSQL</>, and is not needed since errors are
        reported automatically.
       </para>
      </listitem>
     </itemizedlist>
    </para>

    <para>
     This is how this function would look when ported to
     <productname>PostgreSQL</>:

<programlisting>
CREATE OR REPLACE FUNCTION cs_fmt_browser_version(v_name varchar,
                                                  v_version varchar)
RETURNS varchar AS $$
BEGIN
    IF v_version IS NULL THEN
        RETURN v_name;
    END IF;
    RETURN v_name || '/' || v_version;
END;
$$ LANGUAGE plpgsql;
</programlisting>
    </para>
   </example>

   <para>
    <xref linkend="plpgsql-porting-ex2"> shows how to port a
    function that creates another function and how to handle the
    ensuing quoting problems.
   </para>

   <example id="plpgsql-porting-ex2">
    <title>Porting a Function that Creates Another Function from <application>PL/SQL</> to <application>PL/pgSQL</></title>

    <para>
     The following procedure grabs rows from a
     <command>SELECT</command> statement and builds a large function
     with the results in <literal>IF</literal> statements, for the
     sake of efficiency. Notice particularly the differences in the
     cursor and the <literal>FOR</literal> loop.
    </para>

    <para>
     This is the Oracle version:
<programlisting>
CREATE OR REPLACE PROCEDURE cs_update_referrer_type_proc IS
    CURSOR referrer_keys IS 
        SELECT * FROM cs_referrer_keys 
        ORDER BY try_order;

    func_cmd VARCHAR(4000); 
BEGIN 
    func_cmd := 'CREATE OR REPLACE FUNCTION cs_find_referrer_type(v_host IN VARCHAR,
                 v_domain IN VARCHAR, v_url IN VARCHAR) RETURN VARCHAR IS BEGIN'; 

    FOR referrer_key IN referrer_keys LOOP 
        func_cmd := func_cmd ||
          ' IF v_' || referrer_key.kind
          || ' LIKE ''' || referrer_key.key_string
          || ''' THEN RETURN ''' || referrer_key.referrer_type
          || '''; END IF;'; 
    END LOOP; 

    func_cmd := func_cmd || ' RETURN NULL; END;'; 

    EXECUTE IMMEDIATE func_cmd; 
END; 
/ 
show errors;
</programlisting>
    </para>

    <para>
     Here is how this function would end up in <productname>PostgreSQL</>:
<programlisting>
CREATE OR REPLACE FUNCTION cs_update_referrer_type_proc() RETURNS void AS $func$
DECLARE
    referrer_key RECORD;  -- declare a generic record to be used in a FOR
    func_body text;
    func_cmd text;
BEGIN 
    func_body := 'BEGIN' ;

    -- Notice how we scan through the results of a query in a FOR loop
    -- using the FOR &lt;record&gt; construct.

    FOR referrer_key IN SELECT * FROM cs_referrer_keys ORDER BY try_order LOOP
        func_body := func_body ||
          ' IF v_' || referrer_key.kind
          || ' LIKE ' || quote_literal(referrer_key.key_string)
          || ' THEN RETURN ' || quote_literal(referrer_key.referrer_type)
          || '; END IF;' ;
    END LOOP; 

    func_body := func_body || ' RETURN NULL; END;';

    func_cmd :=
      'CREATE OR REPLACE FUNCTION cs_find_referrer_type(v_host varchar,
                                                        v_domain varchar,
                                                        v_url varchar) 
        RETURNS varchar AS '
      || quote_literal(func_body)
      || ' LANGUAGE plpgsql;' ;

    EXECUTE func_cmd;
    RETURN;
END;
$func$ LANGUAGE plpgsql;
</programlisting>
     Notice how the body of the function is built separately and passed
     through <literal>quote_literal</> to double any quote marks in it.  This
     technique is needed because we cannot safely use dollar quoting for
     defining the new function: we do not know for sure what strings will
     be interpolated from the <structfield>referrer_key.key_string</> field.
     (We are assuming here that <structfield>referrer_key.kind</> can be
     trusted to always be <literal>host</>, <literal>domain</>, or
     <literal>url</>, but <structfield>referrer_key.key_string</> might be
     anything, in particular it might contain dollar signs.) This function
     is actually an improvement on the Oracle original, because it will
     not generate broken code when <structfield>referrer_key.key_string</> or
     <structfield>referrer_key.referrer_type</> contain quote marks.
    </para>
   </example>

   <para>
    <xref linkend="plpgsql-porting-ex3"> shows how to port a function
    with <literal>OUT</> parameters and string manipulation.
    <productname>PostgreSQL</> does not have an
    <function>instr</function> function, but you can work around it
    using a combination of other
    functions.<indexterm><primary>instr</></indexterm> In <xref
    linkend="plpgsql-porting-appendix"> there is a
    <application>PL/pgSQL</application> implementation of
    <function>instr</function> that you can use to make your porting
    easier.
   </para>

   <example id="plpgsql-porting-ex3">
    <title>Porting a Procedure With String Manipulation and
    <literal>OUT</> Parameters from <application>PL/SQL</> to
    <application>PL/pgSQL</></title>

    <para>
     The following <productname>Oracle</productname> PL/SQL procedure is used
     to parse a URL and return several elements (host, path, and query).
     In <productname>PostgreSQL</>, functions can return only one value.
     One way to work around this is to make the return value a composite
     type (row type).
    </para>

    <para>
     This is the Oracle version:
<programlisting>
CREATE OR REPLACE PROCEDURE cs_parse_url(
    v_url IN VARCHAR,
    v_host OUT VARCHAR,  -- This will be passed back
    v_path OUT VARCHAR,  -- This one too
    v_query OUT VARCHAR) -- And this one
IS
    a_pos1 INTEGER;
    a_pos2 INTEGER;
BEGIN
    v_host := NULL;
    v_path := NULL;
    v_query := NULL;
    a_pos1 := instr(v_url, '//');

    IF a_pos1 = 0 THEN
        RETURN;
    END IF;
    a_pos2 := instr(v_url, '/', a_pos1 + 2);
    IF a_pos2 = 0 THEN
        v_host := substr(v_url, a_pos1 + 2);
        v_path := '/';
        RETURN;
    END IF;

    v_host := substr(v_url, a_pos1 + 2, a_pos2 - a_pos1 - 2);
    a_pos1 := instr(v_url, '?', a_pos2 + 1);

    IF a_pos1 = 0 THEN
        v_path := substr(v_url, a_pos2);
        RETURN;
    END IF;

    v_path := substr(v_url, a_pos2, a_pos1 - a_pos2);
    v_query := substr(v_url, a_pos1 + 1);
END;
/
show errors;
</programlisting>
    </para>

    <para>
     Here is a possible translation into <application>PL/pgSQL</>:
<programlisting>
CREATE TYPE cs_parse_url_result AS (
    v_host VARCHAR,
    v_path VARCHAR,
    v_query VARCHAR
);

CREATE OR REPLACE FUNCTION cs_parse_url(v_url VARCHAR)
RETURNS cs_parse_url_result AS $$
DECLARE
    res cs_parse_url_result;
    a_pos1 INTEGER;
    a_pos2 INTEGER;
BEGIN
    res.v_host := NULL;
    res.v_path := NULL;
    res.v_query := NULL;
    a_pos1 := instr(v_url, '//');

    IF a_pos1 = 0 THEN
        RETURN res;
    END IF;
    a_pos2 := instr(v_url, '/', a_pos1 + 2);
    IF a_pos2 = 0 THEN
        res.v_host := substr(v_url, a_pos1 + 2);
        res.v_path := '/';
        RETURN res;
    END IF;

    res.v_host := substr(v_url, a_pos1 + 2, a_pos2 - a_pos1 - 2);
    a_pos1 := instr(v_url, '?', a_pos2 + 1);

    IF a_pos1 = 0 THEN
        res.v_path := substr(v_url, a_pos2);
        RETURN res;
    END IF;

    res.v_path := substr(v_url, a_pos2, a_pos1 - a_pos2);
    res.v_query := substr(v_url, a_pos1 + 1);
    RETURN res;
END;
$$ LANGUAGE plpgsql;
</programlisting>

     This function could be used like this:
<programlisting>
SELECT * FROM cs_parse_url('http://foobar.com/query.cgi?baz');
</programlisting>
    </para>
   </example>

   <para>
    <xref linkend="plpgsql-porting-ex4"> shows how to port a procedure
    that uses numerous features that are specific to Oracle.
   </para>

   <example id="plpgsql-porting-ex4">
    <title>Porting a Procedure from <application>PL/SQL</> to <application>PL/pgSQL</></title>

    <para>
     The Oracle version:

<programlisting>
CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id IN INTEGER) IS
    a_running_job_count INTEGER;
    PRAGMA AUTONOMOUS_TRANSACTION;<co id="co.plpgsql-porting-pragma">
BEGIN
    LOCK TABLE cs_jobs IN EXCLUSIVE MODE;<co id="co.plpgsql-porting-locktable">

    SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL;

    IF a_running_job_count &gt; 0 THEN
        COMMIT; -- free lock<co id="co.plpgsql-porting-commit">
        raise_application_error(-20000, 'Unable to create a new job: a job is currently running.');
    END IF;

    DELETE FROM cs_active_job;
    INSERT INTO cs_active_job(job_id) VALUES (v_job_id);

    BEGIN
        INSERT INTO cs_jobs (job_id, start_stamp) VALUES (v_job_id, sysdate);
    EXCEPTION
        WHEN dup_val_on_index THEN NULL; -- don't worry if it already exists
    END;
    COMMIT;
END;
/
show errors
</programlisting>
   </para>

   <para>
    Procedures like this can easily be converted into <productname>PostgreSQL</>
    functions returning <type>void</type>. This procedure in
    particular is interesting because it can teach us some things:

    <calloutlist>
     <callout arearefs="co.plpgsql-porting-pragma">
      <para>
       There is no <literal>PRAGMA</literal> statement in <productname>PostgreSQL</>.
      </para>
     </callout>

     <callout arearefs="co.plpgsql-porting-locktable">
      <para>
       If you do a <command>LOCK TABLE</command> in <application>PL/pgSQL</>,
       the lock will not be released until the calling transaction is
       finished.
      </para>
     </callout>

     <callout arearefs="co.plpgsql-porting-commit">
      <para>
       You cannot issue <command>COMMIT</> in a
       <application>PL/pgSQL</application> function.  The function is
       running within some outer transaction and so <command>COMMIT</>
       would imply terminating the function's execution.  However, in
       this particular case it is not necessary anyway, because the lock
       obtained by the <command>LOCK TABLE</command> will be released when
       we raise an error.
      </para>
     </callout>
    </calloutlist>
   </para>

   <para>
    This is how we could port this procedure to <application>PL/pgSQL</>:

<programlisting>
CREATE OR REPLACE FUNCTION cs_create_job(v_job_id integer) RETURNS void AS $$
DECLARE
    a_running_job_count integer;
BEGIN
    LOCK TABLE cs_jobs IN EXCLUSIVE MODE;

    SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL;

    IF a_running_job_count &gt; 0 THEN
        RAISE EXCEPTION 'Unable to create a new job: a job is currently running';<co id="co.plpgsql-porting-raise">
    END IF;

    DELETE FROM cs_active_job;
    INSERT INTO cs_active_job(job_id) VALUES (v_job_id);

    BEGIN
        INSERT INTO cs_jobs (job_id, start_stamp) VALUES (v_job_id, now());
    EXCEPTION
        WHEN unique_violation THEN <co id="co.plpgsql-porting-exception">
            -- don't worry if it already exists
    END;

    RETURN;
END;
$$ LANGUAGE plpgsql;
</programlisting>

    <calloutlist>
     <callout arearefs="co.plpgsql-porting-raise">
      <para>
       The syntax of <literal>RAISE</> is considerably different from
       Oracle's similar statement.
      </para>
     </callout>
     <callout arearefs="co.plpgsql-porting-exception">
      <para>
       The exception names supported by <application>PL/pgSQL</> are
       different from Oracle's.  The set of built-in exception names
       is much larger (see <xref linkend="errcodes-appendix">).  There
       is not currently a way to declare user-defined exception names.
      </para>
     </callout>
    </calloutlist>

    The main functional difference between this procedure and the
    Oracle equivalent is that the exclusive lock on the <literal>cs_jobs</>
    table will be held until the calling transaction completes.  Also, if
    the caller later aborts (for example due to an error), the effects of
    this procedure will be rolled back.
   </para>
   </example>
  </sect2>

  <sect2 id="plpgsql-porting-other">
   <title>Other Things to Watch For</title>

   <para>
    This section explains a few other things to watch for when porting
    Oracle <application>PL/SQL</> functions to
    <productname>PostgreSQL</productname>.
   </para>

   <sect3 id="plpgsql-porting-exceptions">
    <title>Implicit Rollback after Exceptions</title>

    <para>
     In <application>PL/pgSQL</>, when an exception is caught by an
     <literal>EXCEPTION</> clause, all database changes since the block's
     <literal>BEGIN</> are automatically rolled back.  That is, the behavior
     is equivalent to what you'd get in Oracle with

<programlisting>
    BEGIN
        SAVEPOINT s1;
        ... code here ...
    EXCEPTION
        WHEN ... THEN
            ROLLBACK TO s1;
            ... code here ...
        WHEN ... THEN
            ROLLBACK TO s1;
            ... code here ...
    END;
</programlisting>

     If you are translating an Oracle procedure that uses
     <command>SAVEPOINT</> and <command>ROLLBACK TO</> in this style,
     your task is easy: just omit the <command>SAVEPOINT</> and
     <command>ROLLBACK TO</>.  If you have a procedure that uses
     <command>SAVEPOINT</> and <command>ROLLBACK TO</> in a different way
     then some actual thought will be required.
    </para>
   </sect3>

   <sect3>
    <title><command>EXECUTE</command></title>

    <para>
     The <application>PL/pgSQL</> version of
     <command>EXECUTE</command> works similarly to the
     <application>PL/SQL</> version, but you have to remember to use
     <function>quote_literal(text)</function> and
     <function>quote_string(text)</function> as described in <xref
     linkend="plpgsql-statements-executing-dyn">.  Constructs of the
     type <literal>EXECUTE 'SELECT * FROM $1';</literal> will not
     work unless you use these functions.
    </para>
   </sect3>

   <sect3 id="plpgsql-porting-optimization">
    <title>Optimizing <application>PL/pgSQL</application> Functions</title>

    <para>
     <productname>PostgreSQL</> gives you two function creation
     modifiers to optimize execution: <quote>volatility</> (whether the
     function always returns the same result when given the same
     arguments) and <quote>strictness</quote> (whether the
     function returns null if any argument is null).  Consult the
     <xref linkend="sql-createfunction"> reference page for details.
    </para>

    <para>
     When making use of these optimization attributes, your
     <command>CREATE FUNCTION</command> statement might look something
     like this:

<programlisting>
CREATE FUNCTION foo(...) RETURNS integer AS $$
...
$$ LANGUAGE plpgsql STRICT IMMUTABLE;
</programlisting>
    </para>
   </sect3>
  </sect2>

  <sect2 id="plpgsql-porting-appendix">
   <title>Appendix</title>

   <para>
    This section contains the code for a set of Oracle-compatible
    <function>instr</function> functions that you can use to simplify
    your porting efforts.
   </para>

<programlisting>
--
-- instr functions that mimic Oracle's counterpart
-- Syntax: instr(string1, string2, [n], [m]) where [] denotes optional parameters.
-- 
-- Searches string1 beginning at the nth character for the mth occurrence
-- of string2.  If n is negative, search backwards.  If m is not passed,
-- assume 1 (search starts at first character).
--

CREATE FUNCTION instr(varchar, varchar) RETURNS integer AS $$
DECLARE
    pos integer;
BEGIN
    pos:= instr($1, $2, 1);
    RETURN pos;
END;
$$ LANGUAGE plpgsql STRICT IMMUTABLE;


CREATE FUNCTION instr(string varchar, string_to_search varchar, beg_index integer)
RETURNS integer AS $$
DECLARE
    pos integer NOT NULL DEFAULT 0;
    temp_str varchar;
    beg integer;
    length integer;
    ss_length integer;
BEGIN
    IF beg_index &gt; 0 THEN
        temp_str := substring(string FROM beg_index);
        pos := position(string_to_search IN temp_str);

        IF pos = 0 THEN
            RETURN 0;
        ELSE
            RETURN pos + beg_index - 1;
        END IF;
    ELSE
        ss_length := char_length(string_to_search);
        length := char_length(string);
        beg := length + beg_index - ss_length + 2;

        WHILE beg &gt; 0 LOOP
            temp_str := substring(string FROM beg FOR ss_length);
            pos := position(string_to_search IN temp_str);

            IF pos &gt; 0 THEN
                RETURN beg;
            END IF;

            beg := beg - 1;
        END LOOP;

        RETURN 0;
    END IF;
END;
$$ LANGUAGE plpgsql STRICT IMMUTABLE;


CREATE FUNCTION instr(string varchar, string_to_search varchar,
                      beg_index integer, occur_index integer)
RETURNS integer AS $$
DECLARE
    pos integer NOT NULL DEFAULT 0;
    occur_number integer NOT NULL DEFAULT 0;
    temp_str varchar;
    beg integer;
    i integer;
    length integer;
    ss_length integer;
BEGIN
    IF beg_index &gt; 0 THEN
        beg := beg_index;
        temp_str := substring(string FROM beg_index);

        FOR i IN 1..occur_index LOOP
            pos := position(string_to_search IN temp_str);

            IF i = 1 THEN
                beg := beg + pos - 1;
            ELSE
                beg := beg + pos;
            END IF;

            temp_str := substring(string FROM beg + 1);
        END LOOP;

        IF pos = 0 THEN
            RETURN 0;
        ELSE
            RETURN beg;
        END IF;
    ELSE
        ss_length := char_length(string_to_search);
        length := char_length(string);
        beg := length + beg_index - ss_length + 2;

        WHILE beg &gt; 0 LOOP
            temp_str := substring(string FROM beg FOR ss_length);
            pos := position(string_to_search IN temp_str);

            IF pos &gt; 0 THEN
                occur_number := occur_number + 1;

                IF occur_number = occur_index THEN
                    RETURN beg;
                END IF;
            END IF;

            beg := beg - 1;
        END LOOP;

        RETURN 0;
    END IF;
END;
$$ LANGUAGE plpgsql STRICT IMMUTABLE;
</programlisting>
  </sect2>

 </sect1>

</chapter>

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